1 drop type nearplace cascade;
2 create type nearplace as (
6 drop type nearfeature cascade;
7 create type nearfeature as (
16 drop type nearfeaturecentr cascade;
17 create type nearfeaturecentr as (
27 CREATE TABLE location_area_country () INHERITS (location_area_large);
28 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) TABLESPACE ssd;
30 CREATE TABLE search_name_country () INHERITS (search_name_blank);
31 CREATE INDEX idx_search_name_country_place_id ON search_name_country USING BTREE (place_id) TABLESPACE ssd;
32 CREATE INDEX idx_search_name_country_name_vector ON search_name_country USING GIN (name_vector) WITH (fastupdate = off) TABLESPACE ssd;
35 CREATE TABLE location_area_large_-partition- () INHERITS (location_area_large);
36 CREATE INDEX idx_location_area_large_-partition-_place_id ON location_area_large_-partition- USING BTREE (place_id) TABLESPACE ssd;
37 CREATE INDEX idx_location_area_large_-partition-_geometry ON location_area_large_-partition- USING GIST (geometry) TABLESPACE ssd;
39 CREATE TABLE search_name_-partition- () INHERITS (search_name_blank);
40 CREATE INDEX idx_search_name_-partition-_place_id ON search_name_-partition- USING BTREE (place_id) TABLESPACE ssd;
41 CREATE INDEX idx_search_name_-partition-_centroid ON search_name_-partition- USING GIST (centroid) TABLESPACE ssd;
42 CREATE INDEX idx_search_name_-partition-_name_vector ON search_name_-partition- USING GIN (name_vector) WITH (fastupdate = off) TABLESPACE ssd;
44 CREATE TABLE location_property_-partition- () INHERITS (location_property);
45 CREATE INDEX idx_location_property_-partition-_place_id ON location_property_-partition- USING BTREE (place_id);
46 CREATE INDEX idx_location_property_-partition-_parent_place_id ON location_property_-partition- USING BTREE (parent_place_id);
47 CREATE INDEX idx_location_property_-partition-_housenumber_parent_place_id ON location_property_-partition- USING BTREE (parent_place_id, housenumber);
49 CREATE TABLE location_road_-partition- (
52 country_code VARCHAR(2)
54 SELECT AddGeometryColumn('location_road_-partition-', 'geometry', 4326, 'GEOMETRY', 2);
55 CREATE INDEX idx_location_road_-partition-_geometry ON location_road_-partition- USING GIST (geometry) TABLESPACE ssd;
56 CREATE INDEX idx_location_road_-partition-_place_id ON location_road_-partition- USING BTREE (place_id) TABLESPACE ssd;
60 create or replace function getNearFeatures(in_partition INTEGER, point GEOMETRY, maxrank INTEGER, isin_tokens INT[]) RETURNS setof nearfeaturecentr AS $$
62 r nearfeaturecentr%rowtype;
66 IF in_partition = -partition- THEN
68 SELECT place_id, keywords, rank_address, rank_search, min(ST_Distance(point, centroid)) as distance, isguess, centroid FROM (
69 SELECT * FROM location_area_large_-partition- WHERE ST_Contains(geometry, point) and rank_search < maxrank
71 SELECT * FROM location_area_country WHERE ST_Contains(geometry, point) and rank_search < maxrank
73 GROUP BY place_id, keywords, rank_address, rank_search, isguess, centroid
74 ORDER BY rank_address, isin_tokens && keywords desc, isguess asc,
75 ST_Distance(point, centroid) *
77 WHEN rank_address = 16 AND rank_search = 15 THEN 0.2 -- capital city
78 WHEN rank_address = 16 AND rank_search = 16 THEN 0.25 -- city
79 WHEN rank_address = 16 AND rank_search = 17 THEN 0.5 -- town
80 ELSE 1 END ASC -- everything else
88 RAISE EXCEPTION 'Unknown partition %', in_partition;
93 create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
98 IF in_partition = -partition- THEN
99 DELETE from location_area_large_-partition- WHERE place_id = in_place_id;
104 RAISE EXCEPTION 'Unknown partition %', in_partition;
111 create or replace function insertLocationAreaLarge(
112 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_keywords INTEGER[],
113 in_rank_search INTEGER, in_rank_address INTEGER, in_estimate BOOLEAN,
114 in_centroid GEOMETRY, in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
118 IF in_rank_search <= 4 THEN
119 INSERT INTO location_area_country values (in_partition, in_place_id, in_country_code, in_keywords, in_rank_search, in_rank_address, in_estimate, in_centroid, in_geometry);
124 IF in_partition = -partition- THEN
125 INSERT INTO location_area_large_-partition- values (in_partition, in_place_id, in_country_code, in_keywords, in_rank_search, in_rank_address, in_estimate, in_centroid, in_geometry);
130 RAISE EXCEPTION 'Unknown partition %', in_partition;
136 create or replace function getNearestNamedFeature(in_partition INTEGER, point GEOMETRY, maxrank INTEGER, isin_token INTEGER) RETURNS setof nearfeature AS $$
138 r nearfeature%rowtype;
142 IF in_partition = -partition- THEN
144 SELECT place_id, name_vector, address_rank, search_rank,
145 ST_Distance(centroid, point) as distance, null as isguess
146 FROM search_name_-partition-
147 WHERE name_vector @> ARRAY[isin_token]
148 AND search_rank < maxrank
150 SELECT place_id, name_vector, address_rank, search_rank,
151 ST_Distance(centroid, point) as distance, null as isguess
152 FROM search_name_country
153 WHERE name_vector @> ARRAY[isin_token]
154 AND search_rank < maxrank
155 ORDER BY distance ASC limit 1
163 RAISE EXCEPTION 'Unknown partition %', in_partition;
168 create or replace function getNearestNamedRoadFeature(in_partition INTEGER, point GEOMETRY, isin_token INTEGER)
169 RETURNS setof nearfeature AS $$
171 r nearfeature%rowtype;
175 IF in_partition = -partition- THEN
177 SELECT place_id, name_vector, address_rank, search_rank,
178 ST_Distance(centroid, point) as distance, null as isguess
179 FROM search_name_-partition-
180 WHERE name_vector @> ARRAY[isin_token]
181 AND ST_DWithin(centroid, point, 0.03)
182 AND search_rank between 22 and 27
183 ORDER BY distance ASC limit 1
191 RAISE EXCEPTION 'Unknown partition %', in_partition;
196 create or replace function getNearestPostcode(in_partition INTEGER, point GEOMETRY)
203 IF in_partition = -partition- THEN
205 FROM location_area_large_-partition- join placex using (place_id)
206 WHERE st_contains(location_area_large_-partition-.geometry, point)
207 AND class = 'place' and type = 'postcode'
208 ORDER BY st_distance(location_area_large_-partition-.centroid, point) ASC limit 1
214 RAISE EXCEPTION 'Unknown partition %', in_partition;
219 create or replace function insertSearchName(
220 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2),
221 in_name_vector INTEGER[], in_nameaddress_vector INTEGER[],
222 in_rank_search INTEGER, in_rank_address INTEGER, in_importance FLOAT,
223 in_centroid GEOMETRY) RETURNS BOOLEAN AS $$
227 DELETE FROM search_name WHERE place_id = in_place_id;
228 INSERT INTO search_name values (in_place_id, in_rank_search, in_rank_address, in_importance, in_country_code,
229 in_name_vector, in_nameaddress_vector, in_centroid);
231 IF in_rank_search <= 4 THEN
232 DELETE FROM search_name_country WHERE place_id = in_place_id;
233 INSERT INTO search_name_country values (in_place_id, in_rank_search, in_rank_address, in_importance, in_country_code,
234 in_name_vector, in_nameaddress_vector, in_centroid);
239 IF in_partition = -partition- THEN
240 DELETE FROM search_name_-partition- values WHERE place_id = in_place_id;
241 INSERT INTO search_name_-partition- values (in_place_id, in_rank_search, in_rank_address, 0, in_country_code,
242 in_name_vector, in_nameaddress_vector, in_centroid);
247 RAISE EXCEPTION 'Unknown partition %', in_partition;
253 create or replace function deleteSearchName(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
257 DELETE from search_name WHERE place_id = in_place_id;
258 DELETE from search_name_country WHERE place_id = in_place_id;
261 IF in_partition = -partition- THEN
262 DELETE from search_name_-partition- WHERE place_id = in_place_id;
267 RAISE EXCEPTION 'Unknown partition %', in_partition;
274 create or replace function insertLocationRoad(
275 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
280 IF in_partition = -partition- THEN
281 DELETE FROM location_road_-partition- where place_id = in_place_id;
282 INSERT INTO location_road_-partition- values (in_partition, in_place_id, in_country_code, in_geometry);
287 RAISE EXCEPTION 'Unknown partition %', in_partition;
293 create or replace function deleteRoad(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
298 IF in_partition = -partition- THEN
299 DELETE FROM location_road_-partition- where place_id = in_place_id;
304 RAISE EXCEPTION 'Unknown partition %', in_partition;
311 create or replace function getNearestRoadFeature(in_partition INTEGER, point GEOMETRY) RETURNS setof nearfeature AS $$
313 r nearfeature%rowtype;
314 search_diameter FLOAT;
318 IF in_partition = -partition- THEN
319 search_diameter := 0.00005;
320 WHILE search_diameter < 0.1 LOOP
322 SELECT place_id, null, null, null,
323 ST_Distance(geometry, point) as distance, null as isguess
324 FROM location_road_-partition-
325 WHERE ST_DWithin(geometry, point, search_diameter)
326 ORDER BY distance ASC limit 1
331 search_diameter := search_diameter * 2;
337 RAISE EXCEPTION 'Unknown partition %', in_partition;
342 create or replace function getNearestParellelRoadFeature(in_partition INTEGER, line GEOMETRY) RETURNS setof nearfeature AS $$
344 r nearfeature%rowtype;
345 search_diameter FLOAT;
351 IF st_geometrytype(line) not in ('ST_LineString') THEN
355 p1 := ST_Line_Interpolate_Point(line,0);
356 p2 := ST_Line_Interpolate_Point(line,0.5);
357 p3 := ST_Line_Interpolate_Point(line,1);
360 IF in_partition = -partition- THEN
361 search_diameter := 0.0005;
362 WHILE search_diameter < 0.01 LOOP
364 SELECT place_id, null, null, null,
365 ST_Distance(geometry, line) as distance, null as isguess
366 FROM location_road_-partition-
367 WHERE ST_DWithin(line, geometry, search_diameter)
368 ORDER BY (ST_distance(geometry, p1)+
369 ST_distance(geometry, p2)+
370 ST_distance(geometry, p3)) ASC limit 1
375 search_diameter := search_diameter * 2;
381 RAISE EXCEPTION 'Unknown partition %', in_partition;