2020-02-26 12:42:30 +03:00
|
|
|
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
|
|
|
|
);
|
|
|
|
|
2020-11-09 14:03:37 +03:00
|
|
|
-- feature intersects geoemtry
|
|
|
|
-- for areas and linestrings they must touch at least along a line
|
2020-08-04 13:08:50 +03:00
|
|
|
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;
|
|
|
|
|
2020-10-13 15:57:11 +03:00
|
|
|
create or replace function getNearFeatures(in_partition INTEGER, feature GEOMETRY, maxrank INTEGER) RETURNS setof nearfeaturecentr AS $$
|
2010-10-24 03:12:37 +04:00
|
|
|
DECLARE
|
2012-07-04 00:44:06 +04:00
|
|
|
r nearfeaturecentr%rowtype;
|
2010-10-24 03:12:37 +04:00
|
|
|
BEGIN
|
|
|
|
|
|
|
|
-- start
|
2010-11-09 13:19:36 +03:00
|
|
|
IF in_partition = -partition- THEN
|
2020-11-09 14:03:37 +03:00
|
|
|
FOR r IN
|
|
|
|
SELECT place_id, keywords, rank_address, rank_search,
|
|
|
|
min(ST_Distance(feature, centroid)) as distance,
|
|
|
|
isguess, postcode, centroid
|
2019-07-09 21:47:25 +03:00
|
|
|
FROM location_area_large_-partition-
|
2020-08-04 13:08:50 +03:00
|
|
|
WHERE geometry && feature
|
|
|
|
AND is_relevant_geometry(ST_Relate(geometry, feature), ST_GeometryType(feature))
|
2020-09-25 18:50:36 +03:00
|
|
|
AND rank_address < maxrank
|
2020-11-25 22:33:15 +03:00
|
|
|
-- 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)
|
2017-07-01 23:49:24 +03:00
|
|
|
GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
|
2010-10-24 03:12:37 +04:00
|
|
|
LOOP
|
|
|
|
RETURN NEXT r;
|
|
|
|
END LOOP;
|
|
|
|
RETURN;
|
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
END
|
|
|
|
$$
|
2020-02-26 13:41:49 +03:00
|
|
|
LANGUAGE plpgsql STABLE;
|
2010-10-24 03:12:37 +04:00
|
|
|
|
2020-11-09 14:03:37 +03:00
|
|
|
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
|
2020-11-13 23:34:29 +03:00
|
|
|
ORDER BY bool_or(ST_Intersects(geometry, feature)), distance LIMIT 1;
|
2020-11-09 14:03:37 +03:00
|
|
|
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;
|
|
|
|
|
2013-01-22 11:01:30 +04:00
|
|
|
create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT, in_rank_search INTEGER) RETURNS BOOLEAN AS $$
|
2010-10-24 03:12:37 +04:00
|
|
|
DECLARE
|
|
|
|
BEGIN
|
|
|
|
|
2013-01-22 11:01:30 +04:00
|
|
|
IF in_rank_search <= 4 THEN
|
|
|
|
DELETE from location_area_country WHERE place_id = in_place_id;
|
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
|
|
|
|
2010-10-24 03:12:37 +04:00
|
|
|
-- start
|
2010-11-09 13:19:36 +03:00
|
|
|
IF in_partition = -partition- THEN
|
2010-11-17 18:19:25 +03:00
|
|
|
DELETE from location_area_large_-partition- WHERE place_id = in_place_id;
|
2010-10-24 03:12:37 +04:00
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
|
|
|
|
RETURN FALSE;
|
|
|
|
END
|
|
|
|
$$
|
|
|
|
LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
create or replace function insertLocationAreaLarge(
|
2017-07-01 20:02:25 +03:00
|
|
|
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,
|
2010-10-24 03:12:37 +04:00
|
|
|
in_centroid GEOMETRY, in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
|
|
|
|
DECLARE
|
|
|
|
BEGIN
|
2014-05-18 23:45:29 +04:00
|
|
|
IF in_rank_address = 0 THEN
|
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
2010-10-24 03:12:37 +04:00
|
|
|
|
2019-07-09 21:47:25 +03:00
|
|
|
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);
|
2010-10-26 19:22:41 +04:00
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
|
|
|
|
2010-10-24 03:12:37 +04:00
|
|
|
-- start
|
2010-11-09 13:19:36 +03:00
|
|
|
IF in_partition = -partition- THEN
|
2017-07-01 20:02:25 +03:00
|
|
|
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);
|
2010-10-24 03:12:37 +04:00
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
RETURN FALSE;
|
|
|
|
END
|
|
|
|
$$
|
|
|
|
LANGUAGE plpgsql;
|
|
|
|
|
2020-01-24 00:24:41 +03:00
|
|
|
CREATE OR REPLACE FUNCTION getNearestNamedRoadPlaceId(in_partition INTEGER,
|
2020-01-16 23:43:26 +03:00
|
|
|
point GEOMETRY,
|
|
|
|
isin_token INTEGER[])
|
|
|
|
RETURNS BIGINT
|
|
|
|
AS $$
|
2010-11-09 13:19:36 +03:00
|
|
|
DECLARE
|
2020-01-16 23:43:26 +03:00
|
|
|
parent BIGINT;
|
2010-11-09 13:19:36 +03:00
|
|
|
BEGIN
|
|
|
|
|
|
|
|
-- start
|
|
|
|
IF in_partition = -partition- THEN
|
2020-01-16 23:43:26 +03:00
|
|
|
SELECT place_id FROM search_name_-partition-
|
|
|
|
INTO parent
|
|
|
|
WHERE name_vector && isin_token
|
|
|
|
AND centroid && ST_Expand(point, 0.015)
|
2020-11-13 23:28:14 +03:00
|
|
|
AND address_rank between 26 and 27
|
2020-01-16 23:43:26 +03:00
|
|
|
ORDER BY ST_Distance(centroid, point) ASC limit 1;
|
|
|
|
RETURN parent;
|
2010-11-09 13:19:36 +03:00
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
END
|
|
|
|
$$
|
2020-01-16 23:43:26 +03:00
|
|
|
LANGUAGE plpgsql STABLE;
|
2010-11-09 13:19:36 +03:00
|
|
|
|
2020-01-24 00:24:41 +03:00
|
|
|
CREATE OR REPLACE FUNCTION getNearestNamedPlacePlaceId(in_partition INTEGER,
|
2020-01-16 23:43:26 +03:00
|
|
|
point GEOMETRY,
|
|
|
|
isin_token INTEGER[])
|
|
|
|
RETURNS BIGINT
|
|
|
|
AS $$
|
2013-04-27 02:57:18 +04:00
|
|
|
DECLARE
|
2020-01-16 23:43:26 +03:00
|
|
|
parent BIGINT;
|
2013-04-27 02:57:18 +04:00
|
|
|
BEGIN
|
|
|
|
|
|
|
|
-- start
|
|
|
|
IF in_partition = -partition- THEN
|
2020-01-16 23:43:26 +03:00
|
|
|
SELECT place_id
|
|
|
|
INTO parent
|
|
|
|
FROM search_name_-partition-
|
|
|
|
WHERE name_vector && isin_token
|
|
|
|
AND centroid && ST_Expand(point, 0.04)
|
2020-11-09 14:03:37 +03:00
|
|
|
AND address_rank between 16 and 25
|
2020-01-16 23:43:26 +03:00
|
|
|
ORDER BY ST_Distance(centroid, point) ASC limit 1;
|
|
|
|
RETURN parent;
|
2013-04-27 02:57:18 +04:00
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
END
|
|
|
|
$$
|
2020-02-26 13:41:49 +03:00
|
|
|
LANGUAGE plpgsql STABLE;
|
2013-04-27 02:57:18 +04:00
|
|
|
|
2010-11-09 13:19:36 +03:00
|
|
|
create or replace function insertSearchName(
|
2018-11-20 23:03:56 +03:00
|
|
|
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 $$
|
2010-11-09 13:19:36 +03:00
|
|
|
DECLARE
|
|
|
|
BEGIN
|
|
|
|
-- start
|
|
|
|
IF in_partition = -partition- THEN
|
2010-12-07 16:41:02 +03:00
|
|
|
DELETE FROM search_name_-partition- values WHERE place_id = in_place_id;
|
2014-05-18 23:45:29 +04:00
|
|
|
IF in_rank_address > 0 THEN
|
2020-11-13 23:28:14 +03:00
|
|
|
INSERT INTO search_name_-partition- (place_id, address_rank, name_vector, centroid)
|
|
|
|
values (in_place_id, in_rank_address, in_name_vector, in_geometry);
|
2014-05-18 23:45:29 +04:00
|
|
|
END IF;
|
2010-11-09 13:19:36 +03:00
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
RETURN FALSE;
|
|
|
|
END
|
|
|
|
$$
|
|
|
|
LANGUAGE plpgsql;
|
|
|
|
|
2011-06-14 17:42:46 +04:00
|
|
|
create or replace function deleteSearchName(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
|
2010-11-09 13:19:36 +03:00
|
|
|
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;
|
2011-01-05 17:07:26 +03:00
|
|
|
|
|
|
|
create or replace function insertLocationRoad(
|
2011-06-14 17:42:46 +04:00
|
|
|
in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
|
2011-01-05 17:07:26 +03:00
|
|
|
DECLARE
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
-- start
|
|
|
|
IF in_partition = -partition- THEN
|
|
|
|
DELETE FROM location_road_-partition- where place_id = in_place_id;
|
2017-04-14 16:50:27 +03:00
|
|
|
INSERT INTO location_road_-partition- (partition, place_id, country_code, geometry)
|
|
|
|
values (in_partition, in_place_id, in_country_code, in_geometry);
|
2011-01-05 17:07:26 +03:00
|
|
|
RETURN TRUE;
|
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
RETURN FALSE;
|
|
|
|
END
|
|
|
|
$$
|
|
|
|
LANGUAGE plpgsql;
|
|
|
|
|
2011-06-14 17:42:46 +04:00
|
|
|
create or replace function deleteRoad(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
|
2011-01-05 17:07:26 +03:00
|
|
|
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;
|
|
|
|
|
2020-02-26 12:04:17 +03:00
|
|
|
CREATE OR REPLACE FUNCTION getNearestRoadPlaceId(in_partition INTEGER, point GEOMETRY)
|
|
|
|
RETURNS BIGINT
|
|
|
|
AS $$
|
2011-01-05 17:07:26 +03:00
|
|
|
DECLARE
|
2020-02-26 12:04:17 +03:00
|
|
|
r RECORD;
|
|
|
|
search_diameter FLOAT;
|
2011-01-05 17:07:26 +03:00
|
|
|
BEGIN
|
|
|
|
|
|
|
|
-- start
|
|
|
|
IF in_partition = -partition- THEN
|
|
|
|
search_diameter := 0.00005;
|
|
|
|
WHILE search_diameter < 0.1 LOOP
|
2020-02-26 12:04:17 +03:00
|
|
|
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
|
2011-01-05 17:07:26 +03:00
|
|
|
LOOP
|
2020-02-26 12:04:17 +03:00
|
|
|
RETURN r.place_id;
|
2011-01-05 17:07:26 +03:00
|
|
|
END LOOP;
|
|
|
|
search_diameter := search_diameter * 2;
|
|
|
|
END LOOP;
|
2020-02-26 12:04:17 +03:00
|
|
|
RETURN NULL;
|
2011-01-05 17:07:26 +03:00
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
END
|
|
|
|
$$
|
2020-02-26 13:41:49 +03:00
|
|
|
LANGUAGE plpgsql STABLE;
|
2011-01-05 17:07:26 +03:00
|
|
|
|
2020-02-26 12:14:28 +03:00
|
|
|
CREATE OR REPLACE FUNCTION getNearestParallelRoadFeature(in_partition INTEGER,
|
|
|
|
line GEOMETRY)
|
|
|
|
RETURNS BIGINT
|
|
|
|
AS $$
|
2011-01-05 17:07:26 +03:00
|
|
|
DECLARE
|
2020-02-26 12:14:28 +03:00
|
|
|
r RECORD;
|
|
|
|
search_diameter FLOAT;
|
2011-01-05 17:07:26 +03:00
|
|
|
p1 GEOMETRY;
|
|
|
|
p2 GEOMETRY;
|
|
|
|
p3 GEOMETRY;
|
|
|
|
BEGIN
|
|
|
|
|
2020-02-26 12:14:28 +03:00
|
|
|
IF ST_GeometryType(line) not in ('ST_LineString') THEN
|
|
|
|
RETURN NULL;
|
2011-01-05 17:07:26 +03:00
|
|
|
END IF;
|
|
|
|
|
2014-02-06 11:04:42 +04:00
|
|
|
p1 := ST_LineInterpolatePoint(line,0);
|
|
|
|
p2 := ST_LineInterpolatePoint(line,0.5);
|
|
|
|
p3 := ST_LineInterpolatePoint(line,1);
|
2011-01-05 17:07:26 +03:00
|
|
|
|
|
|
|
-- start
|
|
|
|
IF in_partition = -partition- THEN
|
|
|
|
search_diameter := 0.0005;
|
|
|
|
WHILE search_diameter < 0.01 LOOP
|
2020-02-26 12:14:28 +03:00
|
|
|
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
|
2011-01-05 17:07:26 +03:00
|
|
|
LOOP
|
2020-02-26 12:14:28 +03:00
|
|
|
RETURN r.place_id;
|
2011-01-05 17:07:26 +03:00
|
|
|
END LOOP;
|
|
|
|
search_diameter := search_diameter * 2;
|
|
|
|
END LOOP;
|
2020-02-26 12:14:28 +03:00
|
|
|
RETURN NULL;
|
2011-01-05 17:07:26 +03:00
|
|
|
END IF;
|
|
|
|
-- end
|
|
|
|
|
|
|
|
RAISE EXCEPTION 'Unknown partition %', in_partition;
|
|
|
|
END
|
|
|
|
$$
|
2020-02-26 13:41:49 +03:00
|
|
|
LANGUAGE plpgsql STABLE;
|