mirror of
https://github.com/osm-search/Nominatim.git
synced 2026-02-15 10:57:58 +00:00
rename sql directory to lib-sql
Also introduces a separate constant for the sql directory, so that it can be put separately from the rest of the data if required.
This commit is contained in:
6
lib-sql/aux_tables.sql
Normal file
6
lib-sql/aux_tables.sql
Normal file
@@ -0,0 +1,6 @@
|
||||
CREATE TABLE location_property_aux () INHERITS (location_property);
|
||||
CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
|
||||
CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
|
||||
GRANT SELECT ON location_property_aux TO "{www-user}";
|
||||
|
||||
317
lib-sql/functions/address_lookup.sql
Normal file
317
lib-sql/functions/address_lookup.sql
Normal file
@@ -0,0 +1,317 @@
|
||||
-- Functions for returning address information for a place.
|
||||
|
||||
DROP TYPE IF EXISTS addressline CASCADE;
|
||||
CREATE TYPE addressline as (
|
||||
place_id BIGINT,
|
||||
osm_type CHAR(1),
|
||||
osm_id BIGINT,
|
||||
name HSTORE,
|
||||
class TEXT,
|
||||
type TEXT,
|
||||
place_type TEXT,
|
||||
admin_level INTEGER,
|
||||
fromarea BOOLEAN,
|
||||
isaddress BOOLEAN,
|
||||
rank_address INTEGER,
|
||||
distance FLOAT
|
||||
);
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[])
|
||||
RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
result TEXT;
|
||||
BEGIN
|
||||
IF name is null THEN
|
||||
RETURN null;
|
||||
END IF;
|
||||
|
||||
FOR j IN 1..array_upper(languagepref,1) LOOP
|
||||
IF name ? languagepref[j] THEN
|
||||
result := trim(name->languagepref[j]);
|
||||
IF result != '' THEN
|
||||
return result;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- anything will do as a fallback - just take the first name type thing there is
|
||||
RETURN trim((avals(name))[1]);
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
--housenumber only needed for tiger data
|
||||
CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT,
|
||||
housenumber INTEGER,
|
||||
languagepref TEXT[])
|
||||
RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
result TEXT[];
|
||||
currresult TEXT;
|
||||
prevresult TEXT;
|
||||
location RECORD;
|
||||
BEGIN
|
||||
|
||||
result := '{}';
|
||||
prevresult := '';
|
||||
|
||||
FOR location IN
|
||||
SELECT name,
|
||||
CASE WHEN place_id = for_place_id THEN 99 ELSE rank_address END as rank_address
|
||||
FROM get_addressdata(for_place_id, housenumber)
|
||||
WHERE isaddress order by rank_address desc
|
||||
LOOP
|
||||
currresult := trim(get_name_by_language(location.name, languagepref));
|
||||
IF currresult != prevresult AND currresult IS NOT NULL
|
||||
AND result[(100 - location.rank_address)] IS NULL
|
||||
THEN
|
||||
result[(100 - location.rank_address)] := currresult;
|
||||
prevresult := currresult;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
RETURN array_to_string(result,', ');
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
DROP TYPE IF EXISTS addressdata_place;
|
||||
CREATE TYPE addressdata_place AS (
|
||||
place_id BIGINT,
|
||||
country_code VARCHAR(2),
|
||||
housenumber TEXT,
|
||||
postcode TEXT,
|
||||
class TEXT,
|
||||
type TEXT,
|
||||
name HSTORE,
|
||||
address HSTORE,
|
||||
centroid GEOMETRY
|
||||
);
|
||||
|
||||
-- Compute the list of address parts for the given place.
|
||||
--
|
||||
-- If in_housenumber is greator or equal 0, look for an interpolation.
|
||||
CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER)
|
||||
RETURNS setof addressline
|
||||
AS $$
|
||||
DECLARE
|
||||
place addressdata_place;
|
||||
location RECORD;
|
||||
current_rank_address INTEGER;
|
||||
location_isaddress BOOLEAN;
|
||||
BEGIN
|
||||
-- The place in question might not have a direct entry in place_addressline.
|
||||
-- Look for the parent of such places then and save it in place.
|
||||
|
||||
-- first query osmline (interpolation lines)
|
||||
IF in_housenumber >= 0 THEN
|
||||
SELECT parent_place_id as place_id, country_code,
|
||||
in_housenumber as housenumber, postcode,
|
||||
'place' as class, 'house' as type,
|
||||
null as name, null as address,
|
||||
ST_Centroid(linegeo) as centroid
|
||||
INTO place
|
||||
FROM location_property_osmline
|
||||
WHERE place_id = in_place_id
|
||||
AND in_housenumber between startnumber and endnumber;
|
||||
END IF;
|
||||
|
||||
--then query tiger data
|
||||
-- %NOTIGERDATA% IF 0 THEN
|
||||
IF place IS NULL AND in_housenumber >= 0 THEN
|
||||
SELECT parent_place_id as place_id, 'us' as country_code,
|
||||
in_housenumber as housenumber, postcode,
|
||||
'place' as class, 'house' as type,
|
||||
null as name, null as address,
|
||||
ST_Centroid(linegeo) as centroid
|
||||
INTO place
|
||||
FROM location_property_tiger
|
||||
WHERE place_id = in_place_id
|
||||
AND in_housenumber between startnumber and endnumber;
|
||||
END IF;
|
||||
-- %NOTIGERDATA% END IF;
|
||||
|
||||
-- %NOAUXDATA% IF 0 THEN
|
||||
IF place IS NULL THEN
|
||||
SELECT parent_place_id as place_id, 'us' as country_code,
|
||||
housenumber, postcode,
|
||||
'place' as class, 'house' as type,
|
||||
null as name, null as address,
|
||||
centroid
|
||||
INTO place
|
||||
FROM location_property_aux
|
||||
WHERE place_id = in_place_id;
|
||||
END IF;
|
||||
-- %NOAUXDATA% END IF;
|
||||
|
||||
-- postcode table
|
||||
IF place IS NULL THEN
|
||||
SELECT parent_place_id as place_id, country_code,
|
||||
null::text as housenumber, postcode,
|
||||
'place' as class, 'postcode' as type,
|
||||
null as name, null as address,
|
||||
null as centroid
|
||||
INTO place
|
||||
FROM location_postcode
|
||||
WHERE place_id = in_place_id;
|
||||
END IF;
|
||||
|
||||
-- POI objects in the placex table
|
||||
IF place IS NULL THEN
|
||||
SELECT parent_place_id as place_id, country_code,
|
||||
housenumber, postcode,
|
||||
class, type,
|
||||
name, address,
|
||||
centroid
|
||||
INTO place
|
||||
FROM placex
|
||||
WHERE place_id = in_place_id and rank_search > 27;
|
||||
END IF;
|
||||
|
||||
-- If place is still NULL at this point then the object has its own
|
||||
-- entry in place_address line. However, still check if there is not linked
|
||||
-- place we should be using instead.
|
||||
IF place IS NULL THEN
|
||||
select coalesce(linked_place_id, place_id) as place_id, country_code,
|
||||
housenumber, postcode,
|
||||
class, type,
|
||||
null as name, address,
|
||||
null as centroid
|
||||
INTO place
|
||||
FROM placex where place_id = in_place_id;
|
||||
END IF;
|
||||
|
||||
--RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchpostcode;
|
||||
|
||||
-- --- Return the record for the base entry.
|
||||
|
||||
FOR location IN
|
||||
SELECT placex.place_id, osm_type, osm_id, name,
|
||||
coalesce(extratags->'linked_place', extratags->'place') as place_type,
|
||||
class, type, admin_level,
|
||||
CASE WHEN rank_address = 0 THEN 100
|
||||
WHEN rank_address = 11 THEN 5
|
||||
ELSE rank_address END as rank_address,
|
||||
country_code
|
||||
FROM placex
|
||||
WHERE place_id = place.place_id
|
||||
LOOP
|
||||
--RAISE WARNING '%',location;
|
||||
IF location.rank_address < 4 THEN
|
||||
-- no country locations for ranks higher than country
|
||||
place.country_code := NULL::varchar(2);
|
||||
ELSEIF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
|
||||
place.country_code := location.country_code;
|
||||
END IF;
|
||||
|
||||
RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
|
||||
location.name, location.class, location.type,
|
||||
location.place_type,
|
||||
location.admin_level, true,
|
||||
location.type not in ('postcode', 'postal_code'),
|
||||
location.rank_address, 0)::addressline;
|
||||
|
||||
current_rank_address := location.rank_address;
|
||||
END LOOP;
|
||||
|
||||
-- --- Return records for address parts.
|
||||
|
||||
FOR location IN
|
||||
SELECT placex.place_id, osm_type, osm_id, name, class, type,
|
||||
coalesce(extratags->'linked_place', extratags->'place') as place_type,
|
||||
admin_level, fromarea, isaddress,
|
||||
CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
|
||||
distance, country_code, postcode
|
||||
FROM place_addressline join placex on (address_place_id = placex.place_id)
|
||||
WHERE place_addressline.place_id IN (place.place_id, in_place_id)
|
||||
AND linked_place_id is null
|
||||
AND (placex.country_code IS NULL OR place.country_code IS NULL
|
||||
OR placex.country_code = place.country_code)
|
||||
ORDER BY rank_address desc,
|
||||
(place_addressline.place_id = in_place_id) desc,
|
||||
(fromarea and place.centroid is not null and not isaddress
|
||||
and (place.address is null or avals(name) && avals(place.address))
|
||||
and ST_Contains(geometry, place.centroid)) desc,
|
||||
isaddress desc, fromarea desc,
|
||||
distance asc, rank_search desc
|
||||
LOOP
|
||||
-- RAISE WARNING '%',location;
|
||||
location_isaddress := location.rank_address != current_rank_address;
|
||||
|
||||
IF place.country_code IS NULL AND location.country_code IS NOT NULL THEN
|
||||
place.country_code := location.country_code;
|
||||
END IF;
|
||||
IF location.type in ('postcode', 'postal_code')
|
||||
AND place.postcode is not null
|
||||
THEN
|
||||
-- If the place had a postcode assigned, take this one only
|
||||
-- into consideration when it is an area and the place does not have
|
||||
-- a postcode itself.
|
||||
IF location.fromarea AND location.isaddress
|
||||
AND (place.address is null or not place.address ? 'postcode')
|
||||
THEN
|
||||
place.postcode := null; -- remove the less exact postcode
|
||||
ELSE
|
||||
location_isaddress := false;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN NEXT ROW(location.place_id, location.osm_type, location.osm_id,
|
||||
location.name, location.class, location.type,
|
||||
location.place_type,
|
||||
location.admin_level, location.fromarea,
|
||||
location_isaddress,
|
||||
location.rank_address,
|
||||
location.distance)::addressline;
|
||||
|
||||
current_rank_address := location.rank_address;
|
||||
END LOOP;
|
||||
|
||||
-- If no country was included yet, add the name information from country_name.
|
||||
IF current_rank_address > 4 THEN
|
||||
FOR location IN
|
||||
SELECT name FROM country_name WHERE country_code = place.country_code LIMIT 1
|
||||
LOOP
|
||||
--RAISE WARNING '% % %',current_rank_address,searchcountrycode,countryname;
|
||||
RETURN NEXT ROW(null, null, null, location.name, 'place', 'country', NULL,
|
||||
null, true, true, 4, 0)::addressline;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
-- Finally add some artificial rows.
|
||||
IF place.country_code IS NOT NULL THEN
|
||||
location := ROW(null, null, null, hstore('ref', place.country_code),
|
||||
'place', 'country_code', null, null, true, false, 4, 0)::addressline;
|
||||
RETURN NEXT location;
|
||||
END IF;
|
||||
|
||||
IF place.name IS NOT NULL THEN
|
||||
location := ROW(in_place_id, null, null, place.name, place.class,
|
||||
place.type, null, null, true, true, 29, 0)::addressline;
|
||||
RETURN NEXT location;
|
||||
END IF;
|
||||
|
||||
IF place.housenumber IS NOT NULL THEN
|
||||
location := ROW(null, null, null, hstore('ref', place.housenumber),
|
||||
'place', 'house_number', null, null, true, true, 28, 0)::addressline;
|
||||
RETURN NEXT location;
|
||||
END IF;
|
||||
|
||||
IF place.address is not null and place.address ? '_unlisted_place' THEN
|
||||
RETURN NEXT ROW(null, null, null, hstore('name', place.address->'_unlisted_place'),
|
||||
'place', 'locality', null, null, true, true, 25, 0)::addressline;
|
||||
END IF;
|
||||
|
||||
IF place.postcode is not null THEN
|
||||
location := ROW(null, null, null, hstore('ref', place.postcode), 'place',
|
||||
'postcode', null, null, false, true, 5, 0)::addressline;
|
||||
RETURN NEXT location;
|
||||
END IF;
|
||||
|
||||
RETURN;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
53
lib-sql/functions/aux_property.sql
Normal file
53
lib-sql/functions/aux_property.sql
Normal file
@@ -0,0 +1,53 @@
|
||||
-- Functions for adding external data (currently unused).
|
||||
|
||||
CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
|
||||
in_street TEXT, in_isin TEXT,
|
||||
in_postcode TEXT, in_countrycode char(2))
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
|
||||
newpoints INTEGER;
|
||||
place_centroid GEOMETRY;
|
||||
out_partition INTEGER;
|
||||
out_parent_place_id BIGINT;
|
||||
location RECORD;
|
||||
address_street_word_ids INTEGER[];
|
||||
out_postcode TEXT;
|
||||
|
||||
BEGIN
|
||||
|
||||
place_centroid := ST_Centroid(pointgeo);
|
||||
out_partition := get_partition(in_countrycode);
|
||||
out_parent_place_id := null;
|
||||
|
||||
address_street_word_ids := word_ids_from_name(in_street);
|
||||
IF address_street_word_ids IS NOT NULL THEN
|
||||
out_parent_place_id := getNearestNamedRoadPlaceId(out_partition, place_centroid,
|
||||
address_street_word_ids);
|
||||
END IF;
|
||||
|
||||
IF out_parent_place_id IS NULL THEN
|
||||
SELECT getNearestRoadPlaceId(out_partition, place_centroid)
|
||||
INTO out_parent_place_id;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
out_postcode := in_postcode;
|
||||
IF out_postcode IS NULL THEN
|
||||
SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
|
||||
END IF;
|
||||
-- XXX look into postcode table
|
||||
|
||||
newpoints := 0;
|
||||
insert into location_property_aux (place_id, partition, parent_place_id,
|
||||
housenumber, postcode, centroid)
|
||||
values (nextval('seq_place'), out_partition, out_parent_place_id,
|
||||
in_housenumber, out_postcode, place_centroid);
|
||||
newpoints := newpoints + 1;
|
||||
|
||||
RETURN newpoints;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
125
lib-sql/functions/importance.sql
Normal file
125
lib-sql/functions/importance.sql
Normal file
@@ -0,0 +1,125 @@
|
||||
-- Functions for interpreting wkipedia/wikidata tags and computing importance.
|
||||
|
||||
DROP TYPE IF EXISTS wikipedia_article_match CASCADE;
|
||||
CREATE TYPE wikipedia_article_match as (
|
||||
language TEXT,
|
||||
title TEXT,
|
||||
importance FLOAT
|
||||
);
|
||||
|
||||
DROP TYPE IF EXISTS place_importance CASCADE;
|
||||
CREATE TYPE place_importance as (
|
||||
importance FLOAT,
|
||||
wikipedia TEXT
|
||||
);
|
||||
|
||||
|
||||
-- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
|
||||
CREATE OR REPLACE FUNCTION decode_url_part(p varchar)
|
||||
RETURNS varchar
|
||||
AS $$
|
||||
SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
|
||||
SELECT CASE WHEN length(r.m[1]) = 1 THEN encode(convert_to(r.m[1], 'SQL_ASCII'), 'hex') ELSE substring(r.m[1] from 2 for 2) END
|
||||
FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
|
||||
), '') AS bytea), 'UTF8');
|
||||
$$
|
||||
LANGUAGE SQL IMMUTABLE STRICT;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar)
|
||||
RETURNS varchar
|
||||
AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RETURN decode_url_part(p);
|
||||
EXCEPTION
|
||||
WHEN others THEN return null;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE STRICT;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2))
|
||||
RETURNS wikipedia_article_match
|
||||
AS $$
|
||||
DECLARE
|
||||
langs TEXT[];
|
||||
i INT;
|
||||
wiki_article TEXT;
|
||||
wiki_article_title TEXT;
|
||||
wiki_article_language TEXT;
|
||||
result wikipedia_article_match;
|
||||
BEGIN
|
||||
langs := ARRAY['english','country','ar','bg','ca','cs','da','de','en','es','eo','eu','fa','fr','ko','hi','hr','id','it','he','lt','hu','ms','nl','ja','no','pl','pt','kk','ro','ru','sk','sl','sr','fi','sv','tr','uk','vi','vo','war','zh'];
|
||||
i := 1;
|
||||
WHILE langs[i] IS NOT NULL LOOP
|
||||
wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
|
||||
IF wiki_article is not null THEN
|
||||
wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
|
||||
wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
|
||||
wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
|
||||
--wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
|
||||
wiki_article := replace(wiki_article,' ','_');
|
||||
IF strpos(wiki_article, ':') IN (3,4) THEN
|
||||
wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
|
||||
wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
|
||||
ELSE
|
||||
wiki_article_title := trim(wiki_article);
|
||||
wiki_article_language := CASE WHEN langs[i] = 'english' THEN 'en' WHEN langs[i] = 'country' THEN get_country_language_code(country_code) ELSE langs[i] END;
|
||||
END IF;
|
||||
|
||||
select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
|
||||
from wikipedia_article
|
||||
where language = wiki_article_language and
|
||||
(title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
|
||||
UNION ALL
|
||||
select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
|
||||
from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
|
||||
where wikipedia_redirect.language = wiki_article_language and
|
||||
(from_title = wiki_article_title OR from_title = catch_decode_url_part(wiki_article_title) OR from_title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
|
||||
order by importance desc limit 1 INTO result;
|
||||
|
||||
IF result.language is not null THEN
|
||||
return result;
|
||||
END IF;
|
||||
END IF;
|
||||
i := i + 1;
|
||||
END LOOP;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION compute_importance(extratags HSTORE,
|
||||
country_code varchar(2),
|
||||
osm_type varchar(1), osm_id BIGINT)
|
||||
RETURNS place_importance
|
||||
AS $$
|
||||
DECLARE
|
||||
match RECORD;
|
||||
result place_importance;
|
||||
BEGIN
|
||||
FOR match IN SELECT * FROM get_wikipedia_match(extratags, country_code)
|
||||
WHERE language is not NULL
|
||||
LOOP
|
||||
result.importance := match.importance;
|
||||
result.wikipedia := match.language || ':' || match.title;
|
||||
RETURN result;
|
||||
END LOOP;
|
||||
|
||||
IF extratags ? 'wikidata' THEN
|
||||
FOR match IN SELECT * FROM wikipedia_article
|
||||
WHERE wd_page_title = extratags->'wikidata'
|
||||
ORDER BY language = 'en' DESC, langcount DESC LIMIT 1 LOOP
|
||||
result.importance := match.importance;
|
||||
result.wikipedia := match.language || ':' || match.title;
|
||||
RETURN result;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
RETURN null;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
251
lib-sql/functions/interpolation.sql
Normal file
251
lib-sql/functions/interpolation.sql
Normal file
@@ -0,0 +1,251 @@
|
||||
-- Functions for address interpolation objects in location_property_osmline.
|
||||
|
||||
-- Splits the line at the given point and returns the two parts
|
||||
-- in a multilinestring.
|
||||
CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
|
||||
RETURNS GEOMETRY
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
-- find the parent road of the cut road parts
|
||||
CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT,
|
||||
place TEXT, partition SMALLINT,
|
||||
centroid GEOMETRY, geom GEOMETRY)
|
||||
RETURNS BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
addr_street TEXT;
|
||||
addr_place TEXT;
|
||||
parent_place_id BIGINT;
|
||||
|
||||
waynodes BIGINT[];
|
||||
|
||||
location RECORD;
|
||||
BEGIN
|
||||
addr_street = street;
|
||||
addr_place = place;
|
||||
|
||||
IF addr_street is null and addr_place is null THEN
|
||||
select nodes from planet_osm_ways where id = wayid INTO waynodes;
|
||||
FOR location IN SELECT placex.address from placex
|
||||
where osm_type = 'N' and osm_id = ANY(waynodes)
|
||||
and placex.address is not null
|
||||
and (placex.address ? 'street' or placex.address ? 'place')
|
||||
and indexed_status < 100
|
||||
limit 1 LOOP
|
||||
addr_street = location.address->'street';
|
||||
addr_place = location.address->'place';
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
parent_place_id := find_parent_for_address(addr_street, addr_place,
|
||||
partition, centroid);
|
||||
|
||||
IF parent_place_id is null THEN
|
||||
FOR location IN SELECT place_id FROM placex
|
||||
WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
|
||||
ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
|
||||
ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
|
||||
ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
|
||||
LOOP
|
||||
parent_place_id := location.place_id;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
IF parent_place_id is null THEN
|
||||
RETURN 0;
|
||||
END IF;
|
||||
|
||||
RETURN parent_place_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION osmline_reinsert(node_id BIGINT, geom GEOMETRY)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
existingline RECORD;
|
||||
BEGIN
|
||||
SELECT w.id FROM planet_osm_ways w, location_property_osmline p
|
||||
WHERE p.linegeo && geom and p.osm_id = w.id and p.indexed_status = 0
|
||||
and node_id = any(w.nodes) INTO existingline;
|
||||
|
||||
IF existingline.id is not NULL THEN
|
||||
DELETE FROM location_property_osmline WHERE osm_id = existingline.id;
|
||||
INSERT INTO location_property_osmline (osm_id, address, linegeo)
|
||||
SELECT osm_id, address, geometry FROM place
|
||||
WHERE osm_type = 'W' and osm_id = existingline.id;
|
||||
END IF;
|
||||
|
||||
RETURN true;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION osmline_insert()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
NEW.place_id := nextval('seq_place');
|
||||
NEW.indexed_date := now();
|
||||
|
||||
IF NEW.indexed_status IS NULL THEN
|
||||
IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
|
||||
OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
|
||||
-- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
NEW.indexed_status := 1; --STATUS_NEW
|
||||
NEW.country_code := lower(get_country_code(NEW.linegeo));
|
||||
|
||||
NEW.partition := get_partition(NEW.country_code);
|
||||
NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION osmline_update()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
DECLARE
|
||||
place_centroid GEOMETRY;
|
||||
waynodes BIGINT[];
|
||||
prevnode RECORD;
|
||||
nextnode RECORD;
|
||||
startnumber INTEGER;
|
||||
endnumber INTEGER;
|
||||
housenum INTEGER;
|
||||
linegeo GEOMETRY;
|
||||
splitline GEOMETRY;
|
||||
sectiongeo GEOMETRY;
|
||||
interpol_postcode TEXT;
|
||||
postcode TEXT;
|
||||
BEGIN
|
||||
-- deferred delete
|
||||
IF OLD.indexed_status = 100 THEN
|
||||
delete from location_property_osmline where place_id = OLD.place_id;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
NEW.interpolationtype = NEW.address->'interpolation';
|
||||
|
||||
place_centroid := ST_PointOnSurface(NEW.linegeo);
|
||||
NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
|
||||
NEW.address->'place',
|
||||
NEW.partition, place_centroid, NEW.linegeo);
|
||||
|
||||
IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
|
||||
interpol_postcode := NEW.address->'postcode';
|
||||
housenum := getorcreate_postcode_id(NEW.address->'postcode');
|
||||
ELSE
|
||||
interpol_postcode := NULL;
|
||||
END IF;
|
||||
|
||||
-- if the line was newly inserted, split the line as necessary
|
||||
IF OLD.indexed_status = 1 THEN
|
||||
select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
|
||||
|
||||
IF array_upper(waynodes, 1) IS NULL THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
linegeo := NEW.linegeo;
|
||||
startnumber := NULL;
|
||||
|
||||
FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
|
||||
|
||||
select osm_id, address, geometry
|
||||
from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
|
||||
and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
|
||||
--RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
|
||||
IF nextnode.osm_id IS NOT NULL THEN
|
||||
--RAISE NOTICE 'place_id is not null';
|
||||
IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
|
||||
-- Make sure that the point is actually on the line. That might
|
||||
-- be a bit paranoid but ensures that the algorithm still works
|
||||
-- should osm2pgsql attempt to repair geometries.
|
||||
splitline := split_line_on_node(linegeo, nextnode.geometry);
|
||||
sectiongeo := ST_GeometryN(splitline, 1);
|
||||
linegeo := ST_GeometryN(splitline, 2);
|
||||
ELSE
|
||||
sectiongeo = linegeo;
|
||||
END IF;
|
||||
endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
|
||||
|
||||
IF startnumber IS NOT NULL AND endnumber IS NOT NULL
|
||||
AND startnumber != endnumber
|
||||
AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
|
||||
|
||||
IF (startnumber > endnumber) THEN
|
||||
housenum := endnumber;
|
||||
endnumber := startnumber;
|
||||
startnumber := housenum;
|
||||
sectiongeo := ST_Reverse(sectiongeo);
|
||||
END IF;
|
||||
|
||||
-- determine postcode
|
||||
postcode := coalesce(interpol_postcode,
|
||||
prevnode.address->'postcode',
|
||||
nextnode.address->'postcode',
|
||||
postcode);
|
||||
|
||||
IF postcode is NULL THEN
|
||||
SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
|
||||
END IF;
|
||||
IF postcode is NULL THEN
|
||||
postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
|
||||
END IF;
|
||||
|
||||
IF NEW.startnumber IS NULL THEN
|
||||
NEW.startnumber := startnumber;
|
||||
NEW.endnumber := endnumber;
|
||||
NEW.linegeo := sectiongeo;
|
||||
NEW.postcode := upper(trim(postcode));
|
||||
ELSE
|
||||
insert into location_property_osmline
|
||||
(linegeo, partition, osm_id, parent_place_id,
|
||||
startnumber, endnumber, interpolationtype,
|
||||
address, postcode, country_code,
|
||||
geometry_sector, indexed_status)
|
||||
values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
|
||||
startnumber, endnumber, NEW.interpolationtype,
|
||||
NEW.address, postcode,
|
||||
NEW.country_code, NEW.geometry_sector, 0);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- early break if we are out of line string,
|
||||
-- might happen when a line string loops back on itself
|
||||
IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
|
||||
prevnode := nextnode;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
-- marking descendants for reparenting is not needed, because there are
|
||||
-- actually no descendants for interpolation lines
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
526
lib-sql/functions/normalization.sql
Normal file
526
lib-sql/functions/normalization.sql
Normal file
@@ -0,0 +1,526 @@
|
||||
-- Functions for term normalisation and access to the 'word' table.
|
||||
|
||||
CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
|
||||
AS '{modulepath}/nominatim.so', 'transliteration'
|
||||
LANGUAGE c IMMUTABLE STRICT;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
|
||||
AS '{modulepath}/nominatim.so', 'gettokenstring'
|
||||
LANGUAGE c IMMUTABLE STRICT;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
o TEXT;
|
||||
BEGIN
|
||||
o := public.gettokenstring(public.transliteration(name));
|
||||
RETURN trim(substr(o,1,length(o)));
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
-- returns NULL if the word is too common
|
||||
CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
return_word_id INTEGER;
|
||||
count INTEGER;
|
||||
BEGIN
|
||||
lookup_token := trim(lookup_word);
|
||||
SELECT min(word_id), max(search_name_count) FROM word
|
||||
WHERE word_token = lookup_token and class is null and type is null
|
||||
INTO return_word_id, count;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
|
||||
ELSE
|
||||
IF count > get_maxwordfreq() THEN
|
||||
return_word_id := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
return_word_id INTEGER;
|
||||
BEGIN
|
||||
lookup_token := ' ' || trim(lookup_word);
|
||||
SELECT min(word_id) FROM word
|
||||
WHERE word_token = lookup_token and class='place' and type='house'
|
||||
INTO return_word_id;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, null,
|
||||
'place', 'house', null, 0);
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
lookup_word TEXT;
|
||||
return_word_id INTEGER;
|
||||
BEGIN
|
||||
lookup_word := upper(trim(postcode));
|
||||
lookup_token := ' ' || make_standard_name(lookup_word);
|
||||
SELECT min(word_id) FROM word
|
||||
WHERE word_token = lookup_token and word = lookup_word
|
||||
and class='place' and type='postcode'
|
||||
INTO return_word_id;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word,
|
||||
'place', 'postcode', null, 0);
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT,
|
||||
lookup_country_code varchar(2))
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
return_word_id INTEGER;
|
||||
BEGIN
|
||||
lookup_token := ' '||trim(lookup_word);
|
||||
SELECT min(word_id) FROM word
|
||||
WHERE word_token = lookup_token and country_code=lookup_country_code
|
||||
INTO return_word_id;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, null,
|
||||
null, null, lookup_country_code, 0);
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT,
|
||||
lookup_class text, lookup_type text)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
return_word_id INTEGER;
|
||||
BEGIN
|
||||
lookup_token := ' '||trim(lookup_word);
|
||||
SELECT min(word_id) FROM word
|
||||
WHERE word_token = lookup_token and word = normalized_word
|
||||
and class = lookup_class and type = lookup_type
|
||||
INTO return_word_id;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word,
|
||||
lookup_class, lookup_type, null, 0);
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT,
|
||||
normalized_word TEXT,
|
||||
lookup_class text,
|
||||
lookup_type text,
|
||||
op text)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
return_word_id INTEGER;
|
||||
BEGIN
|
||||
lookup_token := ' '||trim(lookup_word);
|
||||
SELECT min(word_id) FROM word
|
||||
WHERE word_token = lookup_token and word = normalized_word
|
||||
and class = lookup_class and type = lookup_type and operator = op
|
||||
INTO return_word_id;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word,
|
||||
lookup_class, lookup_type, null, 0, op);
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
nospace_lookup_token TEXT;
|
||||
return_word_id INTEGER;
|
||||
BEGIN
|
||||
lookup_token := ' '||trim(lookup_word);
|
||||
SELECT min(word_id) FROM word
|
||||
WHERE word_token = lookup_token and class is null and type is null
|
||||
INTO return_word_id;
|
||||
IF return_word_id IS NULL THEN
|
||||
return_word_id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (return_word_id, lookup_token, src_word,
|
||||
null, null, null, 0);
|
||||
END IF;
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RETURN getorcreate_name_id(lookup_word, '');
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
-- Normalize a string and lookup its word ids (partial words).
|
||||
CREATE OR REPLACE FUNCTION addr_ids_from_name(lookup_word TEXT)
|
||||
RETURNS INTEGER[]
|
||||
AS $$
|
||||
DECLARE
|
||||
words TEXT[];
|
||||
id INTEGER;
|
||||
return_word_id INTEGER[];
|
||||
word_ids INTEGER[];
|
||||
j INTEGER;
|
||||
BEGIN
|
||||
words := string_to_array(make_standard_name(lookup_word), ' ');
|
||||
IF array_upper(words, 1) IS NOT NULL THEN
|
||||
FOR j IN 1..array_upper(words, 1) LOOP
|
||||
IF (words[j] != '') THEN
|
||||
SELECT array_agg(word_id) INTO word_ids
|
||||
FROM word
|
||||
WHERE word_token = words[j] and class is null and type is null;
|
||||
|
||||
IF word_ids IS NULL THEN
|
||||
id := nextval('seq_word');
|
||||
INSERT INTO word VALUES (id, words[j], null, null, null, null, 0);
|
||||
return_word_id := return_word_id || id;
|
||||
ELSE
|
||||
return_word_id := array_merge(return_word_id, word_ids);
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
RETURN return_word_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
-- Normalize a string and look up its name ids (full words).
|
||||
CREATE OR REPLACE FUNCTION word_ids_from_name(lookup_word TEXT)
|
||||
RETURNS INTEGER[]
|
||||
AS $$
|
||||
DECLARE
|
||||
lookup_token TEXT;
|
||||
return_word_ids INTEGER[];
|
||||
BEGIN
|
||||
lookup_token := ' '|| make_standard_name(lookup_word);
|
||||
SELECT array_agg(word_id) FROM word
|
||||
WHERE word_token = lookup_token and class is null and type is null
|
||||
INTO return_word_ids;
|
||||
RETURN return_word_ids;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE STRICT;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION create_country(src HSTORE, country_code varchar(2))
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
s TEXT;
|
||||
w INTEGER;
|
||||
words TEXT[];
|
||||
item RECORD;
|
||||
j INTEGER;
|
||||
BEGIN
|
||||
FOR item IN SELECT (each(src)).* LOOP
|
||||
|
||||
s := make_standard_name(item.value);
|
||||
w := getorcreate_country(s, country_code);
|
||||
|
||||
words := regexp_split_to_array(item.value, E'[,;()]');
|
||||
IF array_upper(words, 1) != 1 THEN
|
||||
FOR j IN 1..array_upper(words, 1) LOOP
|
||||
s := make_standard_name(words[j]);
|
||||
IF s != '' THEN
|
||||
w := getorcreate_country(s, country_code);
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION make_keywords(src HSTORE)
|
||||
RETURNS INTEGER[]
|
||||
AS $$
|
||||
DECLARE
|
||||
result INTEGER[];
|
||||
s TEXT;
|
||||
w INTEGER;
|
||||
words TEXT[];
|
||||
item RECORD;
|
||||
j INTEGER;
|
||||
BEGIN
|
||||
result := '{}'::INTEGER[];
|
||||
|
||||
FOR item IN SELECT (each(src)).* LOOP
|
||||
|
||||
s := make_standard_name(item.value);
|
||||
w := getorcreate_name_id(s, item.value);
|
||||
|
||||
IF not(ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
|
||||
w := getorcreate_word_id(s);
|
||||
|
||||
IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
|
||||
words := string_to_array(s, ' ');
|
||||
IF array_upper(words, 1) IS NOT NULL THEN
|
||||
FOR j IN 1..array_upper(words, 1) LOOP
|
||||
IF (words[j] != '') THEN
|
||||
w = getorcreate_word_id(words[j]);
|
||||
IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
words := regexp_split_to_array(item.value, E'[,;()]');
|
||||
IF array_upper(words, 1) != 1 THEN
|
||||
FOR j IN 1..array_upper(words, 1) LOOP
|
||||
s := make_standard_name(words[j]);
|
||||
IF s != '' THEN
|
||||
w := getorcreate_word_id(s);
|
||||
IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
s := regexp_replace(item.value, '市$', '');
|
||||
IF s != item.value THEN
|
||||
s := make_standard_name(s);
|
||||
IF s != '' THEN
|
||||
w := getorcreate_name_id(s, item.value);
|
||||
IF NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
END LOOP;
|
||||
|
||||
RETURN result;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION make_keywords(src TEXT)
|
||||
RETURNS INTEGER[]
|
||||
AS $$
|
||||
DECLARE
|
||||
result INTEGER[];
|
||||
s TEXT;
|
||||
w INTEGER;
|
||||
words TEXT[];
|
||||
i INTEGER;
|
||||
j INTEGER;
|
||||
BEGIN
|
||||
result := '{}'::INTEGER[];
|
||||
|
||||
s := make_standard_name(src);
|
||||
w := getorcreate_name_id(s, src);
|
||||
|
||||
IF NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
|
||||
w := getorcreate_word_id(s);
|
||||
|
||||
IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
|
||||
words := string_to_array(s, ' ');
|
||||
IF array_upper(words, 1) IS NOT NULL THEN
|
||||
FOR j IN 1..array_upper(words, 1) LOOP
|
||||
IF (words[j] != '') THEN
|
||||
w = getorcreate_word_id(words[j]);
|
||||
IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
words := regexp_split_to_array(src, E'[,;()]');
|
||||
IF array_upper(words, 1) != 1 THEN
|
||||
FOR j IN 1..array_upper(words, 1) LOOP
|
||||
s := make_standard_name(words[j]);
|
||||
IF s != '' THEN
|
||||
w := getorcreate_word_id(s);
|
||||
IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
s := regexp_replace(src, '市$', '');
|
||||
IF s != src THEN
|
||||
s := make_standard_name(s);
|
||||
IF s != '' THEN
|
||||
w := getorcreate_name_id(s, src);
|
||||
IF NOT (ARRAY[w] <@ result) THEN
|
||||
result := result || w;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN result;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION create_poi_search_terms(obj_place_id BIGINT,
|
||||
in_partition SMALLINT,
|
||||
parent_place_id BIGINT,
|
||||
address HSTORE,
|
||||
country TEXT,
|
||||
housenumber TEXT,
|
||||
initial_name_vector INTEGER[],
|
||||
geometry GEOMETRY,
|
||||
OUT name_vector INTEGER[],
|
||||
OUT nameaddress_vector INTEGER[])
|
||||
AS $$
|
||||
DECLARE
|
||||
parent_name_vector INTEGER[];
|
||||
parent_address_vector INTEGER[];
|
||||
addr_place_ids INTEGER[];
|
||||
|
||||
addr_item RECORD;
|
||||
parent_address_place_ids BIGINT[];
|
||||
filtered_address HSTORE;
|
||||
BEGIN
|
||||
nameaddress_vector := '{}'::INTEGER[];
|
||||
|
||||
SELECT s.name_vector, s.nameaddress_vector
|
||||
INTO parent_name_vector, parent_address_vector
|
||||
FROM search_name s
|
||||
WHERE s.place_id = parent_place_id;
|
||||
|
||||
-- Find all address tags that don't appear in the parent search names.
|
||||
SELECT hstore(array_agg(ARRAY[k, v])) INTO filtered_address
|
||||
FROM (SELECT skeys(address) as k, svals(address) as v) a
|
||||
WHERE not addr_ids_from_name(v) && parent_address_vector
|
||||
AND k not in ('country', 'street', 'place', 'postcode',
|
||||
'housenumber', 'streetnumber', 'conscriptionnumber');
|
||||
|
||||
-- Compute all search terms from the addr: tags.
|
||||
IF filtered_address IS NOT NULL THEN
|
||||
FOR addr_item IN
|
||||
SELECT * FROM
|
||||
get_places_for_addr_tags(in_partition, geometry, filtered_address, country)
|
||||
LOOP
|
||||
IF addr_item.place_id is null THEN
|
||||
nameaddress_vector := array_merge(nameaddress_vector,
|
||||
addr_item.keywords);
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
IF parent_address_place_ids is null THEN
|
||||
SELECT array_agg(parent_place_id) INTO parent_address_place_ids
|
||||
FROM place_addressline
|
||||
WHERE place_id = parent_place_id;
|
||||
END IF;
|
||||
|
||||
IF not parent_address_place_ids @> ARRAY[addr_item.place_id] THEN
|
||||
nameaddress_vector := array_merge(nameaddress_vector,
|
||||
addr_item.keywords);
|
||||
|
||||
INSERT INTO place_addressline (place_id, address_place_id, fromarea,
|
||||
isaddress, distance, cached_rank_address)
|
||||
VALUES (obj_place_id, addr_item.place_id, not addr_item.isguess,
|
||||
true, addr_item.distance, addr_item.rank_address);
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
name_vector := initial_name_vector;
|
||||
|
||||
-- Check if the parent covers all address terms.
|
||||
-- If not, create a search name entry with the house number as the name.
|
||||
-- This is unusual for the search_name table but prevents that the place
|
||||
-- is returned when we only search for the street/place.
|
||||
|
||||
IF housenumber is not null and not nameaddress_vector <@ parent_address_vector THEN
|
||||
name_vector := array_merge(name_vector,
|
||||
ARRAY[getorcreate_housenumber_id(make_standard_name(housenumber))]);
|
||||
END IF;
|
||||
|
||||
IF not address ? 'street' and address ? 'place' THEN
|
||||
addr_place_ids := addr_ids_from_name(address->'place');
|
||||
IF not addr_place_ids <@ parent_name_vector THEN
|
||||
-- make sure addr:place terms are always searchable
|
||||
nameaddress_vector := array_merge(nameaddress_vector, addr_place_ids);
|
||||
-- If there is a housenumber, also add the place name as a name,
|
||||
-- so we can search it by the usual housenumber+place algorithms.
|
||||
IF housenumber is not null THEN
|
||||
name_vector := array_merge(name_vector,
|
||||
ARRAY[getorcreate_name_id(make_standard_name(address->'place'))]);
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Cheating here by not recomputing all terms but simply using the ones
|
||||
-- from the parent object.
|
||||
nameaddress_vector := array_merge(nameaddress_vector, parent_name_vector);
|
||||
nameaddress_vector := array_merge(nameaddress_vector, parent_address_vector);
|
||||
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
284
lib-sql/functions/place_triggers.sql
Normal file
284
lib-sql/functions/place_triggers.sql
Normal file
@@ -0,0 +1,284 @@
|
||||
CREATE OR REPLACE FUNCTION place_insert()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
DECLARE
|
||||
i INTEGER;
|
||||
existing RECORD;
|
||||
existingplacex RECORD;
|
||||
existingline RECORD;
|
||||
existinggeometry GEOMETRY;
|
||||
existingplace_id BIGINT;
|
||||
result BOOLEAN;
|
||||
partition INTEGER;
|
||||
BEGIN
|
||||
|
||||
--DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
|
||||
--DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
|
||||
-- filter wrong tupels
|
||||
IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
|
||||
INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
|
||||
VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
|
||||
-- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
|
||||
RETURN null;
|
||||
END IF;
|
||||
|
||||
-- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
|
||||
IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
|
||||
-- Have we already done this place?
|
||||
select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing;
|
||||
|
||||
-- Get the existing place_id
|
||||
select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
|
||||
|
||||
-- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
|
||||
IF existing.osm_type IS NULL THEN
|
||||
DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
|
||||
END IF;
|
||||
|
||||
DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
|
||||
DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
|
||||
|
||||
-- update method for interpolation lines: delete all old interpolation lines with same osm_id (update on place) and insert the new one(s) (they can be split up, if they have > 2 nodes)
|
||||
IF existingline.osm_id IS NOT NULL THEN
|
||||
delete from location_property_osmline where osm_id = NEW.osm_id;
|
||||
END IF;
|
||||
|
||||
-- for interpolations invalidate all nodes on the line
|
||||
update placex p set indexed_status = 2
|
||||
from planet_osm_ways w
|
||||
where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
|
||||
|
||||
|
||||
INSERT INTO location_property_osmline (osm_id, address, linegeo)
|
||||
VALUES (NEW.osm_id, NEW.address, NEW.geometry);
|
||||
|
||||
|
||||
IF existing.osm_type IS NULL THEN
|
||||
return NEW;
|
||||
END IF;
|
||||
|
||||
IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
|
||||
OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
|
||||
OR existing.geometry::text != NEW.geometry::text
|
||||
THEN
|
||||
|
||||
update place set
|
||||
name = NEW.name,
|
||||
address = NEW.address,
|
||||
extratags = NEW.extratags,
|
||||
admin_level = NEW.admin_level,
|
||||
geometry = NEW.geometry
|
||||
where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
|
||||
END IF;
|
||||
|
||||
RETURN NULL;
|
||||
|
||||
ELSE -- insert to placex
|
||||
|
||||
-- Patch in additional country names
|
||||
IF NEW.admin_level = 2 AND NEW.type = 'administrative'
|
||||
AND NEW.address is not NULL AND NEW.address ? 'country' THEN
|
||||
SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
|
||||
IF existing.name IS NOT NULL THEN
|
||||
NEW.name = existing.name || NEW.name;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Have we already done this place?
|
||||
select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing;
|
||||
|
||||
-- Get the existing place_id
|
||||
select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex;
|
||||
|
||||
-- Handle a place changing type by removing the old data
|
||||
-- My generated 'place' types are causing havok because they overlap with real keys
|
||||
-- TODO: move them to their own special purpose key/class to avoid collisions
|
||||
IF existing.osm_type IS NULL THEN
|
||||
DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
|
||||
END IF;
|
||||
|
||||
--DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
|
||||
--DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
|
||||
|
||||
-- Log and discard
|
||||
IF existing.geometry is not null AND st_isvalid(existing.geometry)
|
||||
AND st_area(existing.geometry) > 0.02
|
||||
AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
|
||||
AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
|
||||
THEN
|
||||
INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
|
||||
VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
|
||||
'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
|
||||
RETURN null;
|
||||
END IF;
|
||||
|
||||
DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
|
||||
DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
|
||||
|
||||
-- To paraphrase, if there isn't an existing item, OR if the admin level has changed
|
||||
IF existingplacex.osm_type IS NULL OR
|
||||
(existingplacex.class = 'boundary' AND
|
||||
((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
|
||||
(existingplacex.type != NEW.type)))
|
||||
THEN
|
||||
|
||||
IF existingplacex.osm_type IS NOT NULL THEN
|
||||
-- sanity check: ignore admin_level changes on places with too many active children
|
||||
-- or we end up reindexing entire countries because somebody accidentally deleted admin_level
|
||||
--LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i;
|
||||
--LIMIT INDEXING: IF i > 100000 THEN
|
||||
--LIMIT INDEXING: RETURN null;
|
||||
--LIMIT INDEXING: END IF;
|
||||
END IF;
|
||||
|
||||
IF existing.osm_type IS NOT NULL THEN
|
||||
-- pathological case caused by the triggerless copy into place during initial import
|
||||
-- force delete even for large areas, it will be reinserted later
|
||||
UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
|
||||
DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
|
||||
END IF;
|
||||
|
||||
-- No - process it as a new insertion (hopefully of low rank or it will be slow)
|
||||
insert into placex (osm_type, osm_id, class, type, name,
|
||||
admin_level, address, extratags, geometry)
|
||||
values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
|
||||
NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
|
||||
|
||||
--DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
|
||||
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
|
||||
IF existing.geometry::text != NEW.geometry::text
|
||||
AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
|
||||
AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
|
||||
THEN
|
||||
|
||||
-- Get the version of the geometry actually used (in placex table)
|
||||
select geometry from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type into existinggeometry;
|
||||
|
||||
-- Performance limit
|
||||
IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
|
||||
|
||||
-- re-index points that have moved in / out of the polygon, could be done as a single query but postgres gets the index usage wrong
|
||||
update placex set indexed_status = 2 where indexed_status = 0
|
||||
AND ST_Intersects(NEW.geometry, placex.geometry)
|
||||
AND NOT ST_Intersects(existinggeometry, placex.geometry)
|
||||
AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
|
||||
|
||||
update placex set indexed_status = 2 where indexed_status = 0
|
||||
AND ST_Intersects(existinggeometry, placex.geometry)
|
||||
AND NOT ST_Intersects(NEW.geometry, placex.geometry)
|
||||
AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
|
||||
|
||||
END IF;
|
||||
|
||||
END IF;
|
||||
|
||||
|
||||
IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
|
||||
OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
|
||||
OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
|
||||
OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
|
||||
OR existing.geometry::text != NEW.geometry::text
|
||||
THEN
|
||||
|
||||
update place set
|
||||
name = NEW.name,
|
||||
address = NEW.address,
|
||||
extratags = NEW.extratags,
|
||||
admin_level = NEW.admin_level,
|
||||
geometry = NEW.geometry
|
||||
where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
|
||||
|
||||
|
||||
IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
|
||||
IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
|
||||
-- postcode was deleted, no longer retain in placex
|
||||
DELETE FROM placex where place_id = existingplacex.place_id;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
NEW.name := hstore('ref', NEW.address->'postcode');
|
||||
END IF;
|
||||
|
||||
IF NEW.class in ('boundary')
|
||||
AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
|
||||
DELETE FROM placex where place_id = existingplacex.place_id;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
update placex set
|
||||
name = NEW.name,
|
||||
address = NEW.address,
|
||||
parent_place_id = null,
|
||||
extratags = NEW.extratags,
|
||||
admin_level = NEW.admin_level,
|
||||
indexed_status = 2,
|
||||
geometry = NEW.geometry
|
||||
where place_id = existingplacex.place_id;
|
||||
-- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
|
||||
-- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
|
||||
IF NEW.osm_type='N'
|
||||
and (coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
|
||||
or existing.geometry::text != NEW.geometry::text)
|
||||
THEN
|
||||
result:= osmline_reinsert(NEW.osm_id, NEW.geometry);
|
||||
END IF;
|
||||
|
||||
-- linked places should get potential new naming and addresses
|
||||
IF existingplacex.linked_place_id is not NULL THEN
|
||||
update placex x set
|
||||
name = p.name,
|
||||
extratags = p.extratags,
|
||||
indexed_status = 2
|
||||
from place p
|
||||
where x.place_id = existingplacex.linked_place_id
|
||||
and x.indexed_status = 0
|
||||
and x.osm_type = p.osm_type
|
||||
and x.osm_id = p.osm_id
|
||||
and x.class = p.class;
|
||||
END IF;
|
||||
|
||||
END IF;
|
||||
|
||||
-- Abort the add (we modified the existing place instead)
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION place_delete()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
DECLARE
|
||||
has_rank BOOLEAN;
|
||||
BEGIN
|
||||
|
||||
--DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
|
||||
|
||||
-- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
|
||||
IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
|
||||
SELECT bool_or(not (rank_address = 0 or rank_address > 25)) as ranked FROM placex WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type INTO has_rank;
|
||||
IF has_rank THEN
|
||||
insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- mark for delete
|
||||
UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
|
||||
|
||||
-- interpolations are special
|
||||
IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
|
||||
UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
|
||||
END IF;
|
||||
|
||||
RETURN OLD;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
1083
lib-sql/functions/placex_triggers.sql
Normal file
1083
lib-sql/functions/placex_triggers.sql
Normal file
File diff suppressed because it is too large
Load Diff
40
lib-sql/functions/postcode_triggers.sql
Normal file
40
lib-sql/functions/postcode_triggers.sql
Normal file
@@ -0,0 +1,40 @@
|
||||
-- Trigger functions for location_postcode table.
|
||||
|
||||
|
||||
-- Trigger for updates of location_postcode
|
||||
--
|
||||
-- Computes the parent object the postcode most likely refers to.
|
||||
-- This will be the place that determines the address displayed when
|
||||
-- searching for this postcode.
|
||||
CREATE OR REPLACE FUNCTION postcode_update()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
DECLARE
|
||||
partition SMALLINT;
|
||||
location RECORD;
|
||||
BEGIN
|
||||
IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
NEW.indexed_date = now();
|
||||
|
||||
partition := get_partition(NEW.country_code);
|
||||
|
||||
SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
|
||||
INTO NEW.rank_search, NEW.rank_address;
|
||||
|
||||
NEW.parent_place_id = 0;
|
||||
FOR location IN
|
||||
SELECT place_id
|
||||
FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search)
|
||||
WHERE NOT isguess ORDER BY rank_address DESC, distance asc LIMIT 1
|
||||
LOOP
|
||||
NEW.parent_place_id = location.place_id;
|
||||
END LOOP;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
279
lib-sql/functions/ranking.sql
Normal file
279
lib-sql/functions/ranking.sql
Normal file
@@ -0,0 +1,279 @@
|
||||
-- Functions related to search and address ranks
|
||||
|
||||
-- Return an approximate search radius according to the search rank.
|
||||
CREATE OR REPLACE FUNCTION reverse_place_diameter(rank_search SMALLINT)
|
||||
RETURNS FLOAT
|
||||
AS $$
|
||||
BEGIN
|
||||
IF rank_search <= 4 THEN
|
||||
RETURN 5.0;
|
||||
ELSIF rank_search <= 8 THEN
|
||||
RETURN 1.8;
|
||||
ELSIF rank_search <= 12 THEN
|
||||
RETURN 0.6;
|
||||
ELSIF rank_search <= 17 THEN
|
||||
RETURN 0.16;
|
||||
ELSIF rank_search <= 18 THEN
|
||||
RETURN 0.08;
|
||||
ELSIF rank_search <= 19 THEN
|
||||
RETURN 0.04;
|
||||
END IF;
|
||||
|
||||
RETURN 0.02;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
-- Return an approximate update radius according to the search rank.
|
||||
CREATE OR REPLACE FUNCTION update_place_diameter(rank_search SMALLINT)
|
||||
RETURNS FLOAT
|
||||
AS $$
|
||||
BEGIN
|
||||
-- postcodes
|
||||
IF rank_search = 11 or rank_search = 5 THEN
|
||||
RETURN 0.05;
|
||||
-- anything higher than city is effectively ignored (polygon required)
|
||||
ELSIF rank_search < 16 THEN
|
||||
RETURN 0;
|
||||
ELSIF rank_search < 18 THEN
|
||||
RETURN 0.1;
|
||||
ELSIF rank_search < 20 THEN
|
||||
RETURN 0.05;
|
||||
ELSIF rank_search = 21 THEN
|
||||
RETURN 0.001;
|
||||
ELSIF rank_search < 24 THEN
|
||||
RETURN 0.02;
|
||||
ELSIF rank_search < 26 THEN
|
||||
RETURN 0.002;
|
||||
ELSIF rank_search < 28 THEN
|
||||
RETURN 0.001;
|
||||
END IF;
|
||||
|
||||
RETURN 0;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
-- Compute a base address rank from the extent of the given geometry.
|
||||
--
|
||||
-- This is all simple guess work. We don't need particularly good estimates
|
||||
-- here. This just avoids to have very high ranked address parts in features
|
||||
-- that span very large areas (or vice versa).
|
||||
CREATE OR REPLACE FUNCTION geometry_to_rank(search_rank SMALLINT, geometry GEOMETRY, country_code TEXT)
|
||||
RETURNS SMALLINT
|
||||
AS $$
|
||||
DECLARE
|
||||
area FLOAT;
|
||||
BEGIN
|
||||
IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
|
||||
area := ST_Area(geometry);
|
||||
ELSIF ST_GeometryType(geometry) in ('ST_LineString','ST_MultiLineString') THEN
|
||||
area := (ST_Length(geometry)^2) * 0.1;
|
||||
ELSE
|
||||
RETURN search_rank;
|
||||
END IF;
|
||||
|
||||
-- adjust for the fact that countries come in different sizes
|
||||
IF country_code IN ('ca', 'au', 'ru') THEN
|
||||
area := area / 5;
|
||||
ELSIF country_code IN ('br', 'kz', 'cn', 'us', 'ne', 'gb', 'za', 'sa', 'id', 'eh', 'ml', 'tm') THEN
|
||||
area := area / 3;
|
||||
ELSIF country_code IN ('bo', 'ar', 'sd', 'mn', 'in', 'et', 'cd', 'mz', 'ly', 'cl', 'zm') THEN
|
||||
area := area / 2;
|
||||
END IF;
|
||||
|
||||
IF area > 1 THEN
|
||||
RETURN 7;
|
||||
ELSIF area > 0.1 THEN
|
||||
RETURN 9;
|
||||
ELSIF area > 0.01 THEN
|
||||
RETURN 13;
|
||||
ELSIF area > 0.001 THEN
|
||||
RETURN 17;
|
||||
ELSIF area > 0.0001 THEN
|
||||
RETURN 19;
|
||||
ELSIF area > 0.000005 THEN
|
||||
RETURN 21;
|
||||
END IF;
|
||||
|
||||
RETURN 23;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
-- Guess a ranking for postcodes from country and postcode format.
|
||||
CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
|
||||
OUT rank_search SMALLINT,
|
||||
OUT rank_address SMALLINT)
|
||||
AS $$
|
||||
DECLARE
|
||||
part TEXT;
|
||||
BEGIN
|
||||
rank_search := 30;
|
||||
rank_address := 30;
|
||||
postcode := upper(postcode);
|
||||
|
||||
IF country_code = 'gb' THEN
|
||||
IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
|
||||
rank_search := 25;
|
||||
rank_address := 5;
|
||||
ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
|
||||
rank_search := 23;
|
||||
rank_address := 5;
|
||||
ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
|
||||
rank_search := 21;
|
||||
rank_address := 5;
|
||||
END IF;
|
||||
|
||||
ELSEIF country_code = 'sg' THEN
|
||||
IF postcode ~ '^([0-9]{6})$' THEN
|
||||
rank_search := 25;
|
||||
rank_address := 11;
|
||||
END IF;
|
||||
|
||||
ELSEIF country_code = 'de' THEN
|
||||
IF postcode ~ '^([0-9]{5})$' THEN
|
||||
rank_search := 21;
|
||||
rank_address := 11;
|
||||
END IF;
|
||||
|
||||
ELSE
|
||||
-- Guess at the postcode format and coverage (!)
|
||||
IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
|
||||
rank_search := 21;
|
||||
rank_address := 11;
|
||||
ELSE
|
||||
-- Does it look splitable into and area and local code?
|
||||
part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
|
||||
|
||||
IF part IS NOT NULL THEN
|
||||
rank_search := 25;
|
||||
rank_address := 11;
|
||||
ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
|
||||
rank_search := 21;
|
||||
rank_address := 11;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
-- 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),
|
||||
extended_type VARCHAR(1),
|
||||
place_class TEXT, place_type TEXT,
|
||||
admin_level SMALLINT,
|
||||
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);
|
||||
ELSEIF extended_type = 'N' AND place_class = 'highway' THEN
|
||||
search_rank = 30;
|
||||
address_rank = 30;
|
||||
ELSEIF place_class = 'landuse' AND extended_type != 'A' THEN
|
||||
search_rank = 30;
|
||||
address_rank = 30;
|
||||
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 OR address_rank is NULL THEN
|
||||
search_rank := 30;
|
||||
address_rank := 30;
|
||||
END IF;
|
||||
|
||||
-- some postcorrections
|
||||
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;
|
||||
END IF;
|
||||
|
||||
IF is_major THEN
|
||||
search_rank := search_rank - 1;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_addr_tag_rank(key TEXT, country TEXT,
|
||||
OUT from_rank SMALLINT,
|
||||
OUT to_rank SMALLINT,
|
||||
OUT extent FLOAT)
|
||||
AS $$
|
||||
DECLARE
|
||||
ranks RECORD;
|
||||
BEGIN
|
||||
from_rank := null;
|
||||
|
||||
FOR ranks IN
|
||||
SELECT * FROM
|
||||
(SELECT l.rank_search, l.rank_address FROM address_levels l
|
||||
WHERE (l.country_code = country or l.country_code is NULL)
|
||||
AND l.class = 'place' AND l.type = key
|
||||
ORDER BY l.country_code LIMIT 1) r
|
||||
WHERE rank_address > 0
|
||||
LOOP
|
||||
extent := reverse_place_diameter(ranks.rank_search);
|
||||
|
||||
IF ranks.rank_address <= 4 THEN
|
||||
from_rank := 4;
|
||||
to_rank := 4;
|
||||
ELSEIF ranks.rank_address <= 9 THEN
|
||||
from_rank := 5;
|
||||
to_rank := 9;
|
||||
ELSEIF ranks.rank_address <= 12 THEN
|
||||
from_rank := 10;
|
||||
to_rank := 12;
|
||||
ELSEIF ranks.rank_address <= 16 THEN
|
||||
from_rank := 13;
|
||||
to_rank := 16;
|
||||
ELSEIF ranks.rank_address <= 21 THEN
|
||||
from_rank := 17;
|
||||
to_rank := 21;
|
||||
ELSEIF ranks.rank_address <= 24 THEN
|
||||
from_rank := 22;
|
||||
to_rank := 24;
|
||||
ELSE
|
||||
from_rank := 25;
|
||||
to_rank := 25;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
506
lib-sql/functions/utils.sql
Normal file
506
lib-sql/functions/utils.sql
Normal file
@@ -0,0 +1,506 @@
|
||||
-- Assorted helper functions for the triggers.
|
||||
|
||||
CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry)
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
NEWgeometry geometry;
|
||||
BEGIN
|
||||
-- RAISE WARNING '%',place;
|
||||
NEWgeometry := ST_PointOnSurface(place);
|
||||
RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
|
||||
RETURNS INTEGER[]
|
||||
AS $$
|
||||
DECLARE
|
||||
i INTEGER;
|
||||
r INTEGER[];
|
||||
BEGIN
|
||||
IF array_upper(a, 1) IS NULL THEN
|
||||
RETURN b;
|
||||
END IF;
|
||||
IF array_upper(b, 1) IS NULL THEN
|
||||
RETURN a;
|
||||
END IF;
|
||||
r := a;
|
||||
FOR i IN 1..array_upper(b, 1) LOOP
|
||||
IF NOT (ARRAY[b[i]] <@ r) THEN
|
||||
r := r || b[i];
|
||||
END IF;
|
||||
END LOOP;
|
||||
RETURN r;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
-- Return the node members with a given label from a relation member list
|
||||
-- as a set.
|
||||
--
|
||||
-- \param members Member list in osm2pgsql middle format.
|
||||
-- \param memberLabels Array of labels to accept.
|
||||
--
|
||||
-- \returns Set of OSM ids of nodes that are found.
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION get_rel_node_members(members TEXT[],
|
||||
memberLabels TEXT[])
|
||||
RETURNS SETOF BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
i INTEGER;
|
||||
BEGIN
|
||||
FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
|
||||
IF members[i+1] = ANY(memberLabels)
|
||||
AND upper(substring(members[i], 1, 1))::char(1) = 'N'
|
||||
THEN
|
||||
RETURN NEXT substring(members[i], 2)::bigint;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
RETURN;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
-- Copy 'name' to or from the default language.
|
||||
--
|
||||
-- \param country_code Country code of the object being named.
|
||||
-- \param[inout] name List of names of the object.
|
||||
--
|
||||
-- If the country named by country_code has a single default language,
|
||||
-- then a `name` tag is copied to `name:<country_code>` if this tag does
|
||||
-- not yet exist and vice versa.
|
||||
CREATE OR REPLACE FUNCTION add_default_place_name(country_code VARCHAR(2),
|
||||
INOUT name HSTORE)
|
||||
AS $$
|
||||
DECLARE
|
||||
default_language VARCHAR(10);
|
||||
BEGIN
|
||||
IF name is not null AND array_upper(akeys(name),1) > 1 THEN
|
||||
default_language := get_country_language_code(country_code);
|
||||
IF default_language IS NOT NULL THEN
|
||||
IF name ? 'name' AND NOT name ? ('name:'||default_language) THEN
|
||||
name := name || hstore(('name:'||default_language), (name -> 'name'));
|
||||
ELSEIF name ? ('name:'||default_language) AND NOT name ? 'name' THEN
|
||||
name := name || hstore('name', (name -> ('name:'||default_language)));
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
-- Find the nearest artificial postcode for the given geometry.
|
||||
-- TODO For areas there should not be more than two inside the geometry.
|
||||
CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY)
|
||||
RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
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
|
||||
SELECT min(postcode), count(*) FROM
|
||||
(SELECT postcode FROM location_postcode
|
||||
WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
|
||||
INTO outcode, cnt;
|
||||
|
||||
IF cnt = 1 THEN
|
||||
RETURN outcode;
|
||||
ELSE
|
||||
RETURN null;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
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 outcode;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_country_code(place geometry)
|
||||
RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
place_centre GEOMETRY;
|
||||
nearcountry RECORD;
|
||||
BEGIN
|
||||
place_centre := ST_PointOnSurface(place);
|
||||
|
||||
-- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
|
||||
|
||||
-- Try for a OSM polygon
|
||||
FOR nearcountry IN
|
||||
SELECT country_code from location_area_country
|
||||
WHERE country_code is not null and st_covers(geometry, place_centre) limit 1
|
||||
LOOP
|
||||
RETURN nearcountry.country_code;
|
||||
END LOOP;
|
||||
|
||||
-- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
|
||||
|
||||
-- Try for OSM fallback data
|
||||
-- The order is to deal with places like HongKong that are 'states' within another polygon
|
||||
FOR nearcountry IN
|
||||
SELECT country_code from country_osm_grid
|
||||
WHERE st_covers(geometry, place_centre) order by area asc limit 1
|
||||
LOOP
|
||||
RETURN nearcountry.country_code;
|
||||
END LOOP;
|
||||
|
||||
-- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
|
||||
|
||||
--
|
||||
FOR nearcountry IN
|
||||
SELECT country_code from country_osm_grid
|
||||
WHERE st_dwithin(geometry, place_centre, 0.5)
|
||||
ORDER BY st_distance(geometry, place_centre) asc, area asc limit 1
|
||||
LOOP
|
||||
RETURN nearcountry.country_code;
|
||||
END LOOP;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2))
|
||||
RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
nearcountry RECORD;
|
||||
BEGIN
|
||||
FOR nearcountry IN
|
||||
SELECT distinct country_default_language_code from country_name
|
||||
WHERE country_code = search_country_code limit 1
|
||||
LOOP
|
||||
RETURN lower(nearcountry.country_default_language_code);
|
||||
END LOOP;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10))
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
nearcountry RECORD;
|
||||
BEGIN
|
||||
FOR nearcountry IN
|
||||
SELECT partition from country_name where country_code = in_country_code
|
||||
LOOP
|
||||
RETURN nearcountry.partition;
|
||||
END LOOP;
|
||||
RETURN 0;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
|
||||
-- Find the parent of an address with addr:street/addr:place tag.
|
||||
--
|
||||
-- \param street Value of addr:street or NULL if tag is missing.
|
||||
-- \param place Value of addr:place or NULL if tag is missing.
|
||||
-- \param partition Partition where to search the parent.
|
||||
-- \param centroid Location of the address.
|
||||
--
|
||||
-- \return Place ID of the parent if one was found, NULL otherwise.
|
||||
CREATE OR REPLACE FUNCTION find_parent_for_address(street TEXT, place TEXT,
|
||||
partition SMALLINT,
|
||||
centroid GEOMETRY)
|
||||
RETURNS BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
parent_place_id BIGINT;
|
||||
word_ids INTEGER[];
|
||||
BEGIN
|
||||
IF street is not null THEN
|
||||
-- Check for addr:street attributes
|
||||
-- Note that addr:street links can only be indexed, once the street itself is indexed
|
||||
word_ids := word_ids_from_name(street);
|
||||
IF word_ids is not null THEN
|
||||
parent_place_id := getNearestNamedRoadPlaceId(partition, centroid, word_ids);
|
||||
IF parent_place_id is not null THEN
|
||||
--DEBUG: RAISE WARNING 'Get parent form addr:street: %', parent_place_id;
|
||||
RETURN parent_place_id;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Check for addr:place attributes.
|
||||
IF place is not null THEN
|
||||
word_ids := word_ids_from_name(place);
|
||||
IF word_ids is not null THEN
|
||||
parent_place_id := getNearestNamedPlacePlaceId(partition, centroid, word_ids);
|
||||
IF parent_place_id is not null THEN
|
||||
--DEBUG: RAISE WARNING 'Get parent form addr:place: %', parent_place_id;
|
||||
RETURN parent_place_id;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
DELETE FROM location_area where place_id = OLD_place_id;
|
||||
-- TODO:location_area
|
||||
RETURN true;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
-- Create a bounding box with an extent computed from the radius (in meters)
|
||||
-- which in turn is derived from the given search rank.
|
||||
CREATE OR REPLACE FUNCTION place_node_fuzzy_area(geom GEOMETRY, rank_search INTEGER)
|
||||
RETURNS GEOMETRY
|
||||
AS $$
|
||||
DECLARE
|
||||
radius FLOAT := 500;
|
||||
BEGIN
|
||||
IF rank_search <= 16 THEN -- city
|
||||
radius := 15000;
|
||||
ELSIF rank_search <= 18 THEN -- town
|
||||
radius := 4000;
|
||||
ELSIF rank_search <= 19 THEN -- village
|
||||
radius := 2000;
|
||||
ELSIF rank_search <= 20 THEN -- hamlet
|
||||
radius := 1000;
|
||||
END IF;
|
||||
|
||||
RETURN ST_Envelope(ST_Collect(
|
||||
ST_Project(geom, radius, 0.785398)::geometry,
|
||||
ST_Project(geom, radius, 3.9269908)::geometry));
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION add_location(place_id BIGINT, country_code varchar(2),
|
||||
partition INTEGER, keywords INTEGER[],
|
||||
rank_search INTEGER, rank_address INTEGER,
|
||||
in_postcode TEXT, geometry GEOMETRY,
|
||||
centroid GEOMETRY)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
locationid INTEGER;
|
||||
secgeo GEOMETRY;
|
||||
postcode TEXT;
|
||||
BEGIN
|
||||
PERFORM deleteLocationArea(partition, place_id, rank_search);
|
||||
|
||||
-- add postcode only if it contains a single entry, i.e. ignore postcode lists
|
||||
postcode := NULL;
|
||||
IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
|
||||
postcode := upper(trim (in_postcode));
|
||||
END IF;
|
||||
|
||||
IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
|
||||
FOR secgeo IN select split_geometry(geometry) AS geom LOOP
|
||||
PERFORM insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
|
||||
END LOOP;
|
||||
|
||||
ELSEIF ST_GeometryType(geometry) = 'ST_Point' THEN
|
||||
secgeo := place_node_fuzzy_area(geometry, rank_search);
|
||||
PERFORM insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, centroid, secgeo);
|
||||
|
||||
END IF;
|
||||
|
||||
RETURN true;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT,
|
||||
maxdepth INTEGER)
|
||||
RETURNS SETOF GEOMETRY
|
||||
AS $$
|
||||
DECLARE
|
||||
xmin FLOAT;
|
||||
ymin FLOAT;
|
||||
xmax FLOAT;
|
||||
ymax FLOAT;
|
||||
xmid FLOAT;
|
||||
ymid FLOAT;
|
||||
secgeo GEOMETRY;
|
||||
secbox GEOMETRY;
|
||||
seg INTEGER;
|
||||
geo RECORD;
|
||||
area FLOAT;
|
||||
remainingdepth INTEGER;
|
||||
added INTEGER;
|
||||
BEGIN
|
||||
|
||||
-- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
|
||||
|
||||
IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
|
||||
RETURN NEXT geometry;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
remainingdepth := maxdepth - 1;
|
||||
area := ST_AREA(geometry);
|
||||
IF remainingdepth < 1 OR area < maxarea THEN
|
||||
RETURN NEXT geometry;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
xmin := st_xmin(geometry);
|
||||
xmax := st_xmax(geometry);
|
||||
ymin := st_ymin(geometry);
|
||||
ymax := st_ymax(geometry);
|
||||
secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
|
||||
|
||||
-- if the geometry completely covers the box don't bother to slice any more
|
||||
IF ST_AREA(secbox) = area THEN
|
||||
RETURN NEXT geometry;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
xmid := (xmin+xmax)/2;
|
||||
ymid := (ymin+ymax)/2;
|
||||
|
||||
added := 0;
|
||||
FOR seg IN 1..4 LOOP
|
||||
|
||||
IF seg = 1 THEN
|
||||
secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
|
||||
END IF;
|
||||
IF seg = 2 THEN
|
||||
secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
|
||||
END IF;
|
||||
IF seg = 3 THEN
|
||||
secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
|
||||
END IF;
|
||||
IF seg = 4 THEN
|
||||
secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
|
||||
END IF;
|
||||
|
||||
IF st_intersects(geometry, secbox) THEN
|
||||
secgeo := st_intersection(geometry, secbox);
|
||||
IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
|
||||
FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
|
||||
IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
|
||||
added := added + 1;
|
||||
RETURN NEXT geo.geom;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
RETURN;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
|
||||
RETURNS SETOF GEOMETRY
|
||||
AS $$
|
||||
DECLARE
|
||||
geo RECORD;
|
||||
BEGIN
|
||||
-- 10000000000 is ~~ 1x1 degree
|
||||
FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
|
||||
RETURN NEXT geo.geom;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
osmid BIGINT;
|
||||
osmtype character(1);
|
||||
pclass text;
|
||||
ptype text;
|
||||
BEGIN
|
||||
SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
|
||||
DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
|
||||
DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
|
||||
-- force delete from place/placex by making it a very small geometry
|
||||
UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
|
||||
DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
|
||||
|
||||
RETURN TRUE;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
placegeom GEOMETRY;
|
||||
geom GEOMETRY;
|
||||
diameter FLOAT;
|
||||
rank SMALLINT;
|
||||
BEGIN
|
||||
UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
|
||||
|
||||
SELECT geometry, rank_address INTO placegeom, rank
|
||||
FROM placex WHERE place_id = placeid;
|
||||
|
||||
IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
|
||||
IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon')
|
||||
AND rank > 0
|
||||
THEN
|
||||
FOR geom IN SELECT split_geometry(placegeom) LOOP
|
||||
UPDATE placex SET indexed_status = 2
|
||||
WHERE ST_Intersects(geom, placex.geometry)
|
||||
and indexed_status = 0
|
||||
and ((rank_address = 0 and rank_search > rank) or rank_address > rank)
|
||||
and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
|
||||
END LOOP;
|
||||
ELSE
|
||||
diameter := update_place_diameter(rank);
|
||||
IF diameter > 0 THEN
|
||||
IF rank >= 26 THEN
|
||||
-- roads may cause reparenting for >27 rank places
|
||||
update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
|
||||
ELSEIF rank >= 16 THEN
|
||||
-- up to rank 16, street-less addresses may need reparenting
|
||||
update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or address ? 'place');
|
||||
ELSE
|
||||
-- for all other places the search terms may change as well
|
||||
update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null);
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
|
||||
RETURN FALSE;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
30
lib-sql/indices.src.sql
Normal file
30
lib-sql/indices.src.sql
Normal file
@@ -0,0 +1,30 @@
|
||||
-- Indices used only during search and update.
|
||||
-- These indices are created only after the indexing process is done.
|
||||
|
||||
CREATE INDEX idx_word_word_id on word USING BTREE (word_id) {ts:search-index};
|
||||
|
||||
CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id) {ts:search-index};
|
||||
|
||||
DROP INDEX IF EXISTS idx_placex_rank_search;
|
||||
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search) {ts:search-index};
|
||||
CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address) {ts:search-index};
|
||||
CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) {ts:search-index} where parent_place_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_placex_geometry_reverse_lookupPolygon
|
||||
ON placex USING gist (geometry) {ts:search-index}
|
||||
WHERE St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon')
|
||||
AND rank_address between 4 and 25 AND type != 'postcode'
|
||||
AND name is not null AND indexed_status = 0 AND linked_place_id is null;
|
||||
CREATE INDEX idx_placex_geometry_reverse_placeNode
|
||||
ON placex USING gist (geometry) {ts:search-index}
|
||||
WHERE osm_type = 'N' AND rank_search between 5 and 25
|
||||
AND class = 'place' AND type != 'postcode'
|
||||
AND name is not null AND indexed_status = 0 AND linked_place_id is null;
|
||||
|
||||
GRANT SELECT ON table country_osm_grid to "{www-user}";
|
||||
|
||||
CREATE INDEX idx_osmline_parent_place_id ON location_property_osmline USING BTREE (parent_place_id) {ts:search-index};
|
||||
CREATE INDEX idx_osmline_parent_osm_id ON location_property_osmline USING BTREE (osm_id) {ts:search-index};
|
||||
|
||||
CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id) {ts:search-index};
|
||||
CREATE INDEX idx_postcode_postcode ON location_postcode USING BTREE (postcode) {ts:search-index};
|
||||
6
lib-sql/indices_search.src.sql
Normal file
6
lib-sql/indices_search.src.sql
Normal file
@@ -0,0 +1,6 @@
|
||||
-- Indices used for /search API.
|
||||
-- These indices are created only after the indexing process is done.
|
||||
|
||||
CREATE INDEX idx_search_name_nameaddress_vector ON search_name USING GIN (nameaddress_vector) WITH (fastupdate = off) {ts:search-index};
|
||||
CREATE INDEX idx_search_name_name_vector ON search_name USING GIN (name_vector) WITH (fastupdate = off) {ts:search-index};
|
||||
CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid) {ts:search-index};
|
||||
9
lib-sql/indices_updates.src.sql
Normal file
9
lib-sql/indices_updates.src.sql
Normal file
@@ -0,0 +1,9 @@
|
||||
-- Indices used only during search and update.
|
||||
-- These indices are created only after the indexing process is done.
|
||||
|
||||
CREATE INDEX CONCURRENTLY idx_placex_pendingsector ON placex USING BTREE (rank_address,geometry_sector) {ts:address-index} where indexed_status > 0;
|
||||
|
||||
CREATE INDEX CONCURRENTLY idx_location_area_country_place_id ON location_area_country USING BTREE (place_id) {ts:address-index};
|
||||
|
||||
DROP INDEX CONCURRENTLY IF EXISTS place_id_idx;
|
||||
CREATE UNIQUE INDEX CONCURRENTLY idx_place_osm_unique on place using btree(osm_id,osm_type,class,type) {ts:address-index};
|
||||
370
lib-sql/partition-functions.src.sql
Normal file
370
lib-sql/partition-functions.src.sql
Normal file
@@ -0,0 +1,370 @@
|
||||
DROP TYPE IF EXISTS nearfeaturecentr CASCADE;
|
||||
CREATE TYPE nearfeaturecentr AS (
|
||||
place_id BIGINT,
|
||||
keywords int[],
|
||||
rank_address smallint,
|
||||
rank_search smallint,
|
||||
distance float,
|
||||
isguess boolean,
|
||||
postcode TEXT,
|
||||
centroid GEOMETRY
|
||||
);
|
||||
|
||||
-- feature intersects geoemtry
|
||||
-- for areas and linestrings they must touch at least along a line
|
||||
CREATE OR REPLACE FUNCTION is_relevant_geometry(de9im TEXT, geom_type TEXT)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
BEGIN
|
||||
IF substring(de9im from 1 for 2) != 'FF' THEN
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
|
||||
IF geom_type = 'ST_Point' THEN
|
||||
RETURN substring(de9im from 4 for 1) = '0';
|
||||
END IF;
|
||||
|
||||
IF geom_type in ('ST_LineString', 'ST_MultiLineString') THEN
|
||||
RETURN substring(de9im from 4 for 1) = '1';
|
||||
END IF;
|
||||
|
||||
RETURN substring(de9im from 4 for 1) = '2';
|
||||
END
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
create or replace function getNearFeatures(in_partition INTEGER, feature GEOMETRY, maxrank INTEGER) RETURNS setof nearfeaturecentr AS $$
|
||||
DECLARE
|
||||
r nearfeaturecentr%rowtype;
|
||||
BEGIN
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
FOR r IN
|
||||
SELECT place_id, keywords, rank_address, rank_search,
|
||||
min(ST_Distance(feature, centroid)) as distance,
|
||||
isguess, postcode, centroid
|
||||
FROM location_area_large_-partition-
|
||||
WHERE geometry && feature
|
||||
AND is_relevant_geometry(ST_Relate(geometry, feature), ST_GeometryType(feature))
|
||||
AND rank_address < maxrank
|
||||
-- Postcodes currently still use rank_search to define for which
|
||||
-- features they are relevant.
|
||||
AND not (rank_address in (5, 11) and rank_search > maxrank)
|
||||
GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
|
||||
LOOP
|
||||
RETURN NEXT r;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_places_for_addr_tags(in_partition SMALLINT,
|
||||
feature GEOMETRY,
|
||||
address HSTORE, country TEXT)
|
||||
RETURNS SETOF nearfeaturecentr
|
||||
AS $$
|
||||
DECLARE
|
||||
r nearfeaturecentr%rowtype;
|
||||
item RECORD;
|
||||
BEGIN
|
||||
FOR item IN
|
||||
SELECT (get_addr_tag_rank(key, country)).*, key, name FROM
|
||||
(SELECT skeys(address) as key, svals(address) as name) x
|
||||
LOOP
|
||||
IF item.from_rank is null THEN
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
SELECT place_id, keywords, rank_address, rank_search,
|
||||
min(ST_Distance(feature, centroid)) as distance,
|
||||
isguess, postcode, centroid INTO r
|
||||
FROM location_area_large_-partition-
|
||||
WHERE geometry && ST_Expand(feature, item.extent)
|
||||
AND rank_address between item.from_rank and item.to_rank
|
||||
AND word_ids_from_name(item.name) && keywords
|
||||
GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
|
||||
ORDER BY bool_or(ST_Intersects(geometry, feature)), distance LIMIT 1;
|
||||
IF r.place_id is null THEN
|
||||
-- If we cannot find a place for the term, just return the
|
||||
-- search term for the given name. That ensures that the address
|
||||
-- element can still be searched for, even though it will not be
|
||||
-- displayed.
|
||||
RETURN NEXT ROW(null, addr_ids_from_name(item.name), null, null,
|
||||
null, null, null, null)::nearfeaturecentr;
|
||||
ELSE
|
||||
RETURN NEXT r;
|
||||
END IF;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
END LOOP;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT, in_rank_search INTEGER) RETURNS BOOLEAN AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
|
||||
IF in_rank_search <= 4 THEN
|
||||
DELETE from location_area_country WHERE place_id = in_place_id;
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
DELETE from location_area_large_-partition- WHERE place_id = in_place_id;
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
|
||||
RETURN FALSE;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
create or replace function insertLocationAreaLarge(
|
||||
in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_keywords INTEGER[],
|
||||
in_rank_search INTEGER, in_rank_address INTEGER, in_estimate BOOLEAN, postcode TEXT,
|
||||
in_centroid GEOMETRY, in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
IF in_rank_address = 0 THEN
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
|
||||
IF in_rank_search <= 4 and not in_estimate THEN
|
||||
INSERT INTO location_area_country (place_id, country_code, geometry)
|
||||
values (in_place_id, in_country_code, in_geometry);
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
INSERT INTO location_area_large_-partition- (partition, place_id, country_code, keywords, rank_search, rank_address, isguess, postcode, centroid, geometry)
|
||||
values (in_partition, in_place_id, in_country_code, in_keywords, in_rank_search, in_rank_address, in_estimate, postcode, in_centroid, in_geometry);
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
RETURN FALSE;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getNearestNamedRoadPlaceId(in_partition INTEGER,
|
||||
point GEOMETRY,
|
||||
isin_token INTEGER[])
|
||||
RETURNS BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
parent BIGINT;
|
||||
BEGIN
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
SELECT place_id FROM search_name_-partition-
|
||||
INTO parent
|
||||
WHERE name_vector && isin_token
|
||||
AND centroid && ST_Expand(point, 0.015)
|
||||
AND address_rank between 26 and 27
|
||||
ORDER BY ST_Distance(centroid, point) ASC limit 1;
|
||||
RETURN parent;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getNearestNamedPlacePlaceId(in_partition INTEGER,
|
||||
point GEOMETRY,
|
||||
isin_token INTEGER[])
|
||||
RETURNS BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
parent BIGINT;
|
||||
BEGIN
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
SELECT place_id
|
||||
INTO parent
|
||||
FROM search_name_-partition-
|
||||
WHERE name_vector && isin_token
|
||||
AND centroid && ST_Expand(point, 0.04)
|
||||
AND address_rank between 16 and 25
|
||||
ORDER BY ST_Distance(centroid, point) ASC limit 1;
|
||||
RETURN parent;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
create or replace function insertSearchName(
|
||||
in_partition INTEGER, in_place_id BIGINT, in_name_vector INTEGER[],
|
||||
in_rank_search INTEGER, in_rank_address INTEGER, in_geometry GEOMETRY)
|
||||
RETURNS BOOLEAN AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
DELETE FROM search_name_-partition- values WHERE place_id = in_place_id;
|
||||
IF in_rank_address > 0 THEN
|
||||
INSERT INTO search_name_-partition- (place_id, address_rank, name_vector, centroid)
|
||||
values (in_place_id, in_rank_address, in_name_vector, in_geometry);
|
||||
END IF;
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
RETURN FALSE;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
create or replace function deleteSearchName(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
DELETE from search_name_-partition- WHERE place_id = in_place_id;
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
|
||||
RETURN FALSE;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
create or replace function insertLocationRoad(
|
||||
in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
DELETE FROM location_road_-partition- where place_id = in_place_id;
|
||||
INSERT INTO location_road_-partition- (partition, place_id, country_code, geometry)
|
||||
values (in_partition, in_place_id, in_country_code, in_geometry);
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
RETURN FALSE;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
create or replace function deleteRoad(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
DELETE FROM location_road_-partition- where place_id = in_place_id;
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
|
||||
RETURN FALSE;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getNearestRoadPlaceId(in_partition INTEGER, point GEOMETRY)
|
||||
RETURNS BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
search_diameter FLOAT;
|
||||
BEGIN
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
search_diameter := 0.00005;
|
||||
WHILE search_diameter < 0.1 LOOP
|
||||
FOR r IN
|
||||
SELECT place_id FROM location_road_-partition-
|
||||
WHERE ST_DWithin(geometry, point, search_diameter)
|
||||
ORDER BY ST_Distance(geometry, point) ASC limit 1
|
||||
LOOP
|
||||
RETURN r.place_id;
|
||||
END LOOP;
|
||||
search_diameter := search_diameter * 2;
|
||||
END LOOP;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getNearestParallelRoadFeature(in_partition INTEGER,
|
||||
line GEOMETRY)
|
||||
RETURNS BIGINT
|
||||
AS $$
|
||||
DECLARE
|
||||
r RECORD;
|
||||
search_diameter FLOAT;
|
||||
p1 GEOMETRY;
|
||||
p2 GEOMETRY;
|
||||
p3 GEOMETRY;
|
||||
BEGIN
|
||||
|
||||
IF ST_GeometryType(line) not in ('ST_LineString') THEN
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
p1 := ST_LineInterpolatePoint(line,0);
|
||||
p2 := ST_LineInterpolatePoint(line,0.5);
|
||||
p3 := ST_LineInterpolatePoint(line,1);
|
||||
|
||||
-- start
|
||||
IF in_partition = -partition- THEN
|
||||
search_diameter := 0.0005;
|
||||
WHILE search_diameter < 0.01 LOOP
|
||||
FOR r IN
|
||||
SELECT place_id FROM location_road_-partition-
|
||||
WHERE ST_DWithin(line, geometry, search_diameter)
|
||||
ORDER BY (ST_distance(geometry, p1)+
|
||||
ST_distance(geometry, p2)+
|
||||
ST_distance(geometry, p3)) ASC limit 1
|
||||
LOOP
|
||||
RETURN r.place_id;
|
||||
END LOOP;
|
||||
search_diameter := search_diameter * 2;
|
||||
END LOOP;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- end
|
||||
|
||||
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE;
|
||||
30
lib-sql/partition-tables.src.sql
Normal file
30
lib-sql/partition-tables.src.sql
Normal file
@@ -0,0 +1,30 @@
|
||||
drop table IF EXISTS search_name_blank CASCADE;
|
||||
CREATE TABLE search_name_blank (
|
||||
place_id BIGINT,
|
||||
address_rank smallint,
|
||||
name_vector integer[],
|
||||
centroid GEOMETRY(Geometry, 4326)
|
||||
);
|
||||
|
||||
|
||||
-- start
|
||||
CREATE TABLE location_area_large_-partition- () INHERITS (location_area_large) {ts:address-data};
|
||||
CREATE INDEX idx_location_area_large_-partition-_place_id ON location_area_large_-partition- USING BTREE (place_id) {ts:address-index};
|
||||
CREATE INDEX idx_location_area_large_-partition-_geometry ON location_area_large_-partition- USING GIST (geometry) {ts:address-index};
|
||||
|
||||
CREATE TABLE search_name_-partition- () INHERITS (search_name_blank) {ts:address-data};
|
||||
CREATE INDEX idx_search_name_-partition-_place_id ON search_name_-partition- USING BTREE (place_id) {ts:address-index};
|
||||
CREATE INDEX idx_search_name_-partition-_centroid_street ON search_name_-partition- USING GIST (centroid) {ts:address-index} where address_rank between 26 and 27;
|
||||
CREATE INDEX idx_search_name_-partition-_centroid_place ON search_name_-partition- USING GIST (centroid) {ts:address-index} where address_rank between 2 and 25;
|
||||
|
||||
DROP TABLE IF EXISTS location_road_-partition-;
|
||||
CREATE TABLE location_road_-partition- (
|
||||
place_id BIGINT,
|
||||
partition SMALLINT,
|
||||
country_code VARCHAR(2),
|
||||
geometry GEOMETRY(Geometry, 4326)
|
||||
) {ts:address-data};
|
||||
CREATE INDEX idx_location_road_-partition-_geometry ON location_road_-partition- USING GIST (geometry) {ts:address-index};
|
||||
CREATE INDEX idx_location_road_-partition-_place_id ON location_road_-partition- USING BTREE (place_id) {ts:address-index};
|
||||
|
||||
-- end
|
||||
15
lib-sql/postcode_tables.sql
Normal file
15
lib-sql/postcode_tables.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
DROP TABLE IF EXISTS gb_postcode;
|
||||
CREATE TABLE gb_postcode (
|
||||
id integer,
|
||||
postcode character varying(9),
|
||||
geometry geometry,
|
||||
CONSTRAINT enforce_dims_geometry CHECK ((st_ndims(geometry) = 2)),
|
||||
CONSTRAINT enforce_srid_geometry CHECK ((st_srid(geometry) = 4326))
|
||||
);
|
||||
|
||||
DROP TABLE IF EXISTS us_postcode;
|
||||
CREATE TABLE us_postcode (
|
||||
postcode text,
|
||||
x double precision,
|
||||
y double precision
|
||||
);
|
||||
22
lib-sql/table-triggers.sql
Normal file
22
lib-sql/table-triggers.sql
Normal file
@@ -0,0 +1,22 @@
|
||||
-- insert creates the location tables, creates location indexes if indexed == true
|
||||
CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
|
||||
FOR EACH ROW EXECUTE PROCEDURE placex_insert();
|
||||
CREATE TRIGGER osmline_before_insert BEFORE INSERT ON location_property_osmline
|
||||
FOR EACH ROW EXECUTE PROCEDURE osmline_insert();
|
||||
|
||||
-- update insert creates the location tables
|
||||
CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
|
||||
FOR EACH ROW EXECUTE PROCEDURE placex_update();
|
||||
CREATE TRIGGER osmline_before_update BEFORE UPDATE ON location_property_osmline
|
||||
FOR EACH ROW EXECUTE PROCEDURE osmline_update();
|
||||
|
||||
-- diff update triggers
|
||||
CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
|
||||
FOR EACH ROW EXECUTE PROCEDURE placex_delete();
|
||||
CREATE TRIGGER place_before_delete BEFORE DELETE ON place
|
||||
FOR EACH ROW EXECUTE PROCEDURE place_delete();
|
||||
CREATE TRIGGER place_before_insert BEFORE INSERT ON place
|
||||
FOR EACH ROW EXECUTE PROCEDURE place_insert();
|
||||
|
||||
CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
|
||||
FOR EACH ROW EXECUTE PROCEDURE postcode_update();
|
||||
263
lib-sql/tables.sql
Normal file
263
lib-sql/tables.sql
Normal file
@@ -0,0 +1,263 @@
|
||||
drop table if exists import_status;
|
||||
CREATE TABLE import_status (
|
||||
lastimportdate timestamp with time zone NOT NULL,
|
||||
sequence_id integer,
|
||||
indexed boolean
|
||||
);
|
||||
GRANT SELECT ON import_status TO "{www-user}" ;
|
||||
|
||||
drop table if exists import_osmosis_log;
|
||||
CREATE TABLE import_osmosis_log (
|
||||
batchend timestamp,
|
||||
batchseq integer,
|
||||
batchsize bigint,
|
||||
starttime timestamp,
|
||||
endtime timestamp,
|
||||
event text
|
||||
);
|
||||
|
||||
CREATE TABLE new_query_log (
|
||||
type text,
|
||||
starttime timestamp,
|
||||
ipaddress text,
|
||||
useragent text,
|
||||
language text,
|
||||
query text,
|
||||
searchterm text,
|
||||
endtime timestamp,
|
||||
results integer,
|
||||
format text,
|
||||
secret text
|
||||
);
|
||||
CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
|
||||
GRANT INSERT ON new_query_log TO "{www-user}" ;
|
||||
GRANT UPDATE ON new_query_log TO "{www-user}" ;
|
||||
GRANT SELECT ON new_query_log TO "{www-user}" ;
|
||||
|
||||
GRANT SELECT ON TABLE country_name TO "{www-user}";
|
||||
|
||||
drop table IF EXISTS word;
|
||||
CREATE TABLE word (
|
||||
word_id INTEGER,
|
||||
word_token text,
|
||||
word text,
|
||||
class text,
|
||||
type text,
|
||||
country_code varchar(2),
|
||||
search_name_count INTEGER,
|
||||
operator TEXT
|
||||
) {ts:search-data};
|
||||
CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
|
||||
GRANT SELECT ON word TO "{www-user}" ;
|
||||
DROP SEQUENCE IF EXISTS seq_word;
|
||||
CREATE SEQUENCE seq_word start 1;
|
||||
|
||||
drop table IF EXISTS location_area CASCADE;
|
||||
CREATE TABLE location_area (
|
||||
place_id BIGINT,
|
||||
keywords INTEGER[],
|
||||
partition SMALLINT,
|
||||
rank_search SMALLINT NOT NULL,
|
||||
rank_address SMALLINT NOT NULL,
|
||||
country_code VARCHAR(2),
|
||||
isguess BOOL,
|
||||
postcode TEXT,
|
||||
centroid GEOMETRY(Point, 4326),
|
||||
geometry GEOMETRY(Geometry, 4326)
|
||||
);
|
||||
|
||||
CREATE TABLE location_area_large () INHERITS (location_area);
|
||||
|
||||
DROP TABLE IF EXISTS location_area_country;
|
||||
CREATE TABLE location_area_country (
|
||||
place_id BIGINT,
|
||||
country_code varchar(2),
|
||||
geometry GEOMETRY(Geometry, 4326)
|
||||
) {ts:address-data};
|
||||
CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts:address-index};
|
||||
|
||||
|
||||
drop table IF EXISTS location_property CASCADE;
|
||||
CREATE TABLE location_property (
|
||||
place_id BIGINT,
|
||||
parent_place_id BIGINT,
|
||||
partition SMALLINT,
|
||||
housenumber TEXT,
|
||||
postcode TEXT,
|
||||
centroid GEOMETRY(Point, 4326)
|
||||
);
|
||||
|
||||
CREATE TABLE location_property_aux () INHERITS (location_property);
|
||||
CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
|
||||
CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
|
||||
GRANT SELECT ON location_property_aux TO "{www-user}";
|
||||
|
||||
CREATE TABLE location_property_tiger (
|
||||
place_id BIGINT,
|
||||
parent_place_id BIGINT,
|
||||
startnumber INTEGER,
|
||||
endnumber INTEGER,
|
||||
partition SMALLINT,
|
||||
linegeo GEOMETRY,
|
||||
interpolationtype TEXT,
|
||||
postcode TEXT);
|
||||
GRANT SELECT ON location_property_tiger TO "{www-user}";
|
||||
|
||||
drop table if exists location_property_osmline;
|
||||
CREATE TABLE location_property_osmline (
|
||||
place_id BIGINT NOT NULL,
|
||||
osm_id BIGINT,
|
||||
parent_place_id BIGINT,
|
||||
geometry_sector INTEGER,
|
||||
indexed_date TIMESTAMP,
|
||||
startnumber INTEGER,
|
||||
endnumber INTEGER,
|
||||
partition SMALLINT,
|
||||
indexed_status SMALLINT,
|
||||
linegeo GEOMETRY,
|
||||
interpolationtype TEXT,
|
||||
address HSTORE,
|
||||
postcode TEXT,
|
||||
country_code VARCHAR(2)
|
||||
){ts:search-data};
|
||||
CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
|
||||
CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
|
||||
CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
|
||||
GRANT SELECT ON location_property_osmline TO "{www-user}";
|
||||
|
||||
drop table IF EXISTS search_name;
|
||||
CREATE TABLE search_name (
|
||||
place_id BIGINT,
|
||||
importance FLOAT,
|
||||
search_rank SMALLINT,
|
||||
address_rank SMALLINT,
|
||||
name_vector integer[],
|
||||
nameaddress_vector integer[],
|
||||
country_code varchar(2),
|
||||
centroid GEOMETRY(Geometry, 4326)
|
||||
) {ts:search-data};
|
||||
CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
|
||||
|
||||
drop table IF EXISTS place_addressline;
|
||||
CREATE TABLE place_addressline (
|
||||
place_id BIGINT,
|
||||
address_place_id BIGINT,
|
||||
distance FLOAT,
|
||||
cached_rank_address SMALLINT,
|
||||
fromarea boolean,
|
||||
isaddress boolean
|
||||
) {ts:search-data};
|
||||
CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
|
||||
|
||||
drop table if exists placex;
|
||||
CREATE TABLE placex (
|
||||
place_id BIGINT NOT NULL,
|
||||
parent_place_id BIGINT,
|
||||
linked_place_id BIGINT,
|
||||
importance FLOAT,
|
||||
indexed_date TIMESTAMP,
|
||||
geometry_sector INTEGER,
|
||||
rank_address SMALLINT,
|
||||
rank_search SMALLINT,
|
||||
partition SMALLINT,
|
||||
indexed_status SMALLINT,
|
||||
LIKE place INCLUDING CONSTRAINTS,
|
||||
wikipedia TEXT, -- calculated wikipedia article name (language:title)
|
||||
country_code varchar(2),
|
||||
housenumber TEXT,
|
||||
postcode TEXT,
|
||||
centroid GEOMETRY(Geometry, 4326)
|
||||
) {ts:search-data};
|
||||
CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
|
||||
CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
|
||||
CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
|
||||
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
|
||||
CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
|
||||
CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name')) {ts:address-index} WHERE osm_type='N' and rank_search < 26;
|
||||
CREATE INDEX idx_placex_wikidata on placex USING BTREE ((extratags -> 'wikidata')) {ts:address-index} WHERE extratags ? 'wikidata' and class = 'place' and osm_type = 'N' and rank_search < 26;
|
||||
|
||||
DROP SEQUENCE IF EXISTS seq_place;
|
||||
CREATE SEQUENCE seq_place start 1;
|
||||
GRANT SELECT on placex to "{www-user}" ;
|
||||
GRANT SELECT ON search_name to "{www-user}" ;
|
||||
GRANT SELECT on place_addressline to "{www-user}" ;
|
||||
GRANT SELECT ON seq_word to "{www-user}" ;
|
||||
GRANT SELECT ON planet_osm_ways to "{www-user}" ;
|
||||
GRANT SELECT ON planet_osm_rels to "{www-user}" ;
|
||||
GRANT SELECT on location_area to "{www-user}" ;
|
||||
|
||||
-- Table for synthetic postcodes.
|
||||
DROP TABLE IF EXISTS location_postcode;
|
||||
CREATE TABLE location_postcode (
|
||||
place_id BIGINT,
|
||||
parent_place_id BIGINT,
|
||||
rank_search SMALLINT,
|
||||
rank_address SMALLINT,
|
||||
indexed_status SMALLINT,
|
||||
indexed_date TIMESTAMP,
|
||||
country_code varchar(2),
|
||||
postcode TEXT,
|
||||
geometry GEOMETRY(Geometry, 4326)
|
||||
);
|
||||
CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
|
||||
GRANT SELECT ON location_postcode TO "{www-user}" ;
|
||||
|
||||
DROP TABLE IF EXISTS import_polygon_error;
|
||||
CREATE TABLE import_polygon_error (
|
||||
osm_id BIGINT,
|
||||
osm_type CHAR(1),
|
||||
class TEXT NOT NULL,
|
||||
type TEXT NOT NULL,
|
||||
name HSTORE,
|
||||
country_code varchar(2),
|
||||
updated timestamp,
|
||||
errormessage text,
|
||||
prevgeometry GEOMETRY(Geometry, 4326),
|
||||
newgeometry GEOMETRY(Geometry, 4326)
|
||||
);
|
||||
CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
|
||||
GRANT SELECT ON import_polygon_error TO "{www-user}";
|
||||
|
||||
DROP TABLE IF EXISTS import_polygon_delete;
|
||||
CREATE TABLE import_polygon_delete (
|
||||
osm_id BIGINT,
|
||||
osm_type CHAR(1),
|
||||
class TEXT NOT NULL,
|
||||
type TEXT NOT NULL
|
||||
);
|
||||
CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
|
||||
GRANT SELECT ON import_polygon_delete TO "{www-user}";
|
||||
|
||||
DROP SEQUENCE IF EXISTS file;
|
||||
CREATE SEQUENCE file start 1;
|
||||
|
||||
-- null table so it won't error
|
||||
-- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
|
||||
CREATE TABLE wikipedia_article (
|
||||
language text NOT NULL,
|
||||
title text NOT NULL,
|
||||
langcount integer,
|
||||
othercount integer,
|
||||
totalcount integer,
|
||||
lat double precision,
|
||||
lon double precision,
|
||||
importance double precision,
|
||||
osm_type character(1),
|
||||
osm_id bigint,
|
||||
wd_page_title text,
|
||||
instance_of text
|
||||
);
|
||||
ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
|
||||
CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
|
||||
|
||||
CREATE TABLE wikipedia_redirect (
|
||||
language text,
|
||||
from_title text,
|
||||
to_title text
|
||||
);
|
||||
ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
|
||||
|
||||
-- osm2pgsql does not create indexes on the middle tables for Nominatim
|
||||
-- Add one for lookup of associated street relations.
|
||||
CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];
|
||||
13
lib-sql/tiger_import_finish.sql
Normal file
13
lib-sql/tiger_import_finish.sql
Normal file
@@ -0,0 +1,13 @@
|
||||
--index only on parent_place_id
|
||||
CREATE INDEX idx_location_property_tiger_parent_place_id_imp ON location_property_tiger_import (parent_place_id) {ts:aux-index};
|
||||
CREATE UNIQUE INDEX idx_location_property_tiger_place_id_imp ON location_property_tiger_import (place_id) {ts:aux-index};
|
||||
|
||||
GRANT SELECT ON location_property_tiger_import TO "{www-user}";
|
||||
|
||||
DROP TABLE IF EXISTS location_property_tiger;
|
||||
ALTER TABLE location_property_tiger_import RENAME TO location_property_tiger;
|
||||
|
||||
ALTER INDEX idx_location_property_tiger_parent_place_id_imp RENAME TO idx_location_property_tiger_housenumber_parent_place_id;
|
||||
ALTER INDEX idx_location_property_tiger_place_id_imp RENAME TO idx_location_property_tiger_place_id;
|
||||
|
||||
DROP FUNCTION tiger_line_import (linegeo geometry, in_startnumber integer, in_endnumber integer, interpolationtype text, in_street text, in_isin text, in_postcode text);
|
||||
82
lib-sql/tiger_import_start.sql
Normal file
82
lib-sql/tiger_import_start.sql
Normal file
@@ -0,0 +1,82 @@
|
||||
DROP TABLE IF EXISTS location_property_tiger_import;
|
||||
CREATE TABLE location_property_tiger_import (linegeo GEOMETRY, place_id BIGINT, partition INTEGER, parent_place_id BIGINT, startnumber INTEGER, endnumber INTEGER, interpolationtype TEXT, postcode TEXT);
|
||||
|
||||
CREATE OR REPLACE FUNCTION tiger_line_import(linegeo GEOMETRY, in_startnumber INTEGER,
|
||||
in_endnumber INTEGER, interpolationtype TEXT,
|
||||
in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
|
||||
AS $$
|
||||
DECLARE
|
||||
startnumber INTEGER;
|
||||
endnumber INTEGER;
|
||||
stepsize INTEGER;
|
||||
numberrange INTEGER;
|
||||
place_centroid GEOMETRY;
|
||||
out_partition INTEGER;
|
||||
out_parent_place_id BIGINT;
|
||||
location RECORD;
|
||||
address_street_word_ids INTEGER[];
|
||||
|
||||
BEGIN
|
||||
|
||||
IF in_endnumber > in_startnumber THEN
|
||||
startnumber = in_startnumber;
|
||||
endnumber = in_endnumber;
|
||||
ELSE
|
||||
startnumber = in_endnumber;
|
||||
endnumber = in_startnumber;
|
||||
END IF;
|
||||
|
||||
IF startnumber < 0 THEN
|
||||
RAISE WARNING 'Negative house number range (% to %) on %, %', startnumber, endnumber, in_street, in_isin;
|
||||
RETURN 0;
|
||||
END IF;
|
||||
|
||||
numberrange := endnumber - startnumber;
|
||||
|
||||
IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
|
||||
startnumber := startnumber + 1;
|
||||
stepsize := 2;
|
||||
ELSE
|
||||
IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
|
||||
stepsize := 2;
|
||||
ELSE -- everything else assumed to be 'all'
|
||||
stepsize := 1;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Filter out really broken tiger data
|
||||
IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
|
||||
AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
|
||||
RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
|
||||
ST_length(linegeo)/(numberrange::float/stepsize::float);
|
||||
RETURN 0;
|
||||
END IF;
|
||||
|
||||
place_centroid := ST_Centroid(linegeo);
|
||||
out_partition := get_partition('us');
|
||||
out_parent_place_id := null;
|
||||
|
||||
address_street_word_ids := word_ids_from_name(in_street);
|
||||
IF address_street_word_ids IS NOT NULL THEN
|
||||
out_parent_place_id := getNearestNamedRoadPlaceId(out_partition, place_centroid,
|
||||
address_street_word_ids);
|
||||
END IF;
|
||||
|
||||
IF out_parent_place_id IS NULL THEN
|
||||
SELECT getNearestParallelRoadFeature(out_partition, linegeo)
|
||||
INTO out_parent_place_id;
|
||||
END IF;
|
||||
|
||||
IF out_parent_place_id IS NULL THEN
|
||||
SELECT getNearestRoadPlaceId(out_partition, place_centroid)
|
||||
INTO out_parent_place_id;
|
||||
END IF;
|
||||
|
||||
--insert street(line) into import table
|
||||
insert into location_property_tiger_import (linegeo, place_id, partition, parent_place_id, startnumber, endnumber, interpolationtype, postcode)
|
||||
values (linegeo, nextval('seq_place'), out_partition, out_parent_place_id, startnumber, endnumber, interpolationtype, in_postcode);
|
||||
|
||||
RETURN 1;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
58
lib-sql/update-postcodes.sql
Normal file
58
lib-sql/update-postcodes.sql
Normal file
@@ -0,0 +1,58 @@
|
||||
-- Create a temporary table with postcodes from placex.
|
||||
|
||||
CREATE TEMP TABLE tmp_new_postcode_locations AS
|
||||
SELECT country_code,
|
||||
upper(trim (both ' ' from address->'postcode')) as pc,
|
||||
ST_Centroid(ST_Collect(ST_Centroid(geometry))) as centroid
|
||||
FROM placex
|
||||
WHERE address ? 'postcode'
|
||||
AND address->'postcode' NOT SIMILAR TO '%(,|;|:)%'
|
||||
AND geometry IS NOT null
|
||||
GROUP BY country_code, pc;
|
||||
|
||||
CREATE INDEX idx_tmp_new_postcode_locations
|
||||
ON tmp_new_postcode_locations (pc, country_code);
|
||||
|
||||
-- add extra US postcodes
|
||||
INSERT INTO tmp_new_postcode_locations (country_code, pc, centroid)
|
||||
SELECT 'us', postcode, ST_SetSRID(ST_Point(x,y),4326)
|
||||
FROM us_postcode u
|
||||
WHERE NOT EXISTS (SELECT 0 FROM tmp_new_postcode_locations new
|
||||
WHERE new.country_code = 'us' AND new.pc = u.postcode);
|
||||
-- add extra UK postcodes
|
||||
INSERT INTO tmp_new_postcode_locations (country_code, pc, centroid)
|
||||
SELECT 'gb', postcode, geometry FROM gb_postcode g
|
||||
WHERE NOT EXISTS (SELECT 0 FROM tmp_new_postcode_locations new
|
||||
WHERE new.country_code = 'gb' and new.pc = g.postcode);
|
||||
|
||||
-- Remove all postcodes that are no longer valid
|
||||
DELETE FROM location_postcode old
|
||||
WHERE NOT EXISTS(SELECT 0 FROM tmp_new_postcode_locations new
|
||||
WHERE old.postcode = new.pc
|
||||
AND old.country_code = new.country_code);
|
||||
|
||||
-- Update geometries where necessary
|
||||
UPDATE location_postcode old SET geometry = new.centroid, indexed_status = 1
|
||||
FROM tmp_new_postcode_locations new
|
||||
WHERE old.postcode = new.pc AND old.country_code = new.country_code
|
||||
AND ST_AsText(old.geometry) != ST_AsText(new.centroid);
|
||||
|
||||
-- Remove all postcodes that already exist from the temporary table
|
||||
DELETE FROM tmp_new_postcode_locations new
|
||||
WHERE EXISTS(SELECT 0 FROM location_postcode old
|
||||
WHERE old.postcode = new.pc AND old.country_code = new.country_code);
|
||||
|
||||
-- Add newly added postcode
|
||||
INSERT INTO location_postcode
|
||||
(place_id, indexed_status, country_code, postcode, geometry)
|
||||
SELECT nextval('seq_place'), 1, country_code, pc, centroid
|
||||
FROM tmp_new_postcode_locations new;
|
||||
|
||||
-- Remove unused word entries
|
||||
DELETE FROM word
|
||||
WHERE class = 'place' AND type = 'postcode'
|
||||
AND NOT EXISTS (SELECT 0 FROM location_postcode p
|
||||
WHERE p.postcode = word.word);
|
||||
|
||||
-- Finally index the newly inserted postcodes
|
||||
UPDATE location_postcode SET indexed_status = 0 WHERE indexed_status > 0;
|
||||
14
lib-sql/words.sql
Normal file
14
lib-sql/words.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
CREATE TABLE word_frequencies AS
|
||||
(SELECT unnest(make_keywords(v)) as id, sum(count) as count
|
||||
FROM (select svals(name) as v, count(*)from place group by v) cnt
|
||||
WHERE v is not null
|
||||
GROUP BY id);
|
||||
|
||||
select count(getorcreate_postcode_id(v)) from (select distinct address->'postcode' as v from place where address ? 'postcode') as w where v is not null;
|
||||
select count(getorcreate_housenumber_id(make_standard_name(v))) from (select distinct address->'housenumber' as v from place where address ? 'housenumber') as w;
|
||||
|
||||
-- copy the word frequencies
|
||||
update word set search_name_count = count from word_frequencies wf where wf.id = word.word_id;
|
||||
|
||||
-- and drop the temporary frequency table again
|
||||
drop table word_frequencies;
|
||||
11
lib-sql/words_from_search_name.sql
Normal file
11
lib-sql/words_from_search_name.sql
Normal file
@@ -0,0 +1,11 @@
|
||||
DROP TABLE IF EXISTS word_frequencies;
|
||||
CREATE TABLE word_frequencies AS
|
||||
SELECT unnest(name_vector) as id, count(*) FROM search_name GROUP BY id;
|
||||
|
||||
CREATE INDEX idx_word_frequencies ON word_frequencies(id);
|
||||
|
||||
UPDATE word SET search_name_count = count
|
||||
FROM word_frequencies
|
||||
WHERE word_token like ' %' and word_id = id;
|
||||
|
||||
DROP TABLE word_frequencies;
|
||||
Reference in New Issue
Block a user