source: subversion/applications/utils/export/osm2pgsql-intarray/gazetteer/gazetteer-functions.sql.in @ 28719

Last change on this file since 28719 was 24286, checked in by hholzgra, 9 years ago
  • install gazetteer helper files in $datadir/gazetteer
  • install osm2pgsql helper files in $datadir/osm2pgsql
  • set up right gazetteer.so path in installed gazetteer-functions.sql file
File size: 103.7 KB
Line 
1--DROP TRIGGER IF EXISTS place_before_insert on placex;
2--DROP TRIGGER IF EXISTS place_before_update on placex;
3--CREATE TYPE addresscalculationtype AS (
4--  word text,
5--  score integer
6--);
7
8
9CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
10  AS $$
11DECLARE
12BEGIN
13  RETURN c||'|'||t;
14END;
15$$
16LANGUAGE plpgsql IMMUTABLE;
17
18CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
19  AS $$
20DECLARE
21  NEWgeometry geometry;
22BEGIN
23  NEWgeometry := place;
24  IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
25    RETURN true;
26  END IF;
27  RETURN false;
28END;
29$$
30LANGUAGE plpgsql IMMUTABLE;
31
32CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
33  AS $$
34DECLARE
35  NEWgeometry geometry;
36BEGIN
37  NEWgeometry := place;
38  IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
39    NEWgeometry := ST_buffer(NEWgeometry,0);
40    IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
41      RETURN ST_SetSRID(ST_Point(0,0),4326);
42    END IF;
43  END IF;
44  RETURN NEWgeometry;
45END;
46$$
47LANGUAGE plpgsql IMMUTABLE;
48
49CREATE OR REPLACE FUNCTION geometry_sector(place geometry) RETURNS INTEGER
50  AS $$
51DECLARE
52  NEWgeometry geometry;
53BEGIN
54--  RAISE WARNING '%',place;
55  NEWgeometry := place;
56  IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
57    NEWgeometry := ST_buffer(NEWgeometry,0);
58    IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
59      RETURN NULL;
60    END IF;
61  END IF;
62  RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
63END;
64$$
65LANGUAGE plpgsql IMMUTABLE;
66
67CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER
68  AS $$
69DECLARE
70  NEWgeometry geometry;
71BEGIN
72--  RAISE WARNING '%',osmid;
73  IF osmid = 61315 THEN
74    return null;
75  END IF;
76  NEWgeometry := place;
77  IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
78    NEWgeometry := ST_buffer(NEWgeometry,0);
79    IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN 
80      RETURN NULL;
81    END IF;
82  END IF;
83  RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
84END;
85$$
86LANGUAGE plpgsql IMMUTABLE;
87
88CREATE OR REPLACE FUNCTION geometry_index(place geometry,indexed BOOLEAN,name keyvalue[]) RETURNS INTEGER
89  AS $$
90BEGIN
91IF indexed THEN RETURN NULL; END IF;
92IF name is null THEN RETURN NULL; END IF;
93RETURN geometry_sector(place);
94END;
95$$
96LANGUAGE plpgsql IMMUTABLE;
97
98CREATE OR REPLACE FUNCTION create_tables_location_point() RETURNS BOOLEAN
99  AS $$
100DECLARE
101  i INTEGER;
102  postfix TEXT;
103BEGIN
104
105  FOR i in 0..26 LOOP
106
107    postfix := '_'||i;
108
109    EXECUTE 'drop table IF EXISTS location_point'||postfix;
110    EXECUTE 'CREATE TABLE location_point'||postfix||' ('||
111      'place_id bigint,'||
112      'country_code varchar(2),'||
113      'name keyvalue[],'||
114      'keywords TEXT[],'||
115      'rank_search INTEGER NOT NULL,'||
116      'rank_address INTEGER NOT NULL,'||
117      'is_area BOOLEAN NOT NULL'||
118      ')';
119   EXECUTE 'SELECT AddGeometryColumn(''location_point'||postfix||''', ''centroid'', 4326, ''POINT'', 2)';
120   EXECUTE 'CREATE INDEX idx_location_point'||postfix||'_centroid ON location_point'||postfix||' USING GIST (centroid)';
121   EXECUTE 'CREATE INDEX idx_location_point'||postfix||'_sector ON location_point'||postfix||' USING BTREE (geometry_sector(centroid))';
122   EXECUTE 'CREATE INDEX idx_location_point'||postfix||'_place_id ON location_point'||postfix||' USING BTREE (place_id)';
123   EXECUTE 'CLUSTER location_point'||postfix||' USING idx_location_point'||postfix||'_sector';
124  END LOOP;
125
126  RETURN true;
127END;
128$$
129LANGUAGE plpgsql;
130
131CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
132  AS 'gazetteerdir/gazetteer.so', 'transliteration'
133LANGUAGE c IMMUTABLE STRICT;
134
135CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
136  AS 'gazetteerdir/gazetteer.so', 'gettokenstring'
137LANGUAGE c IMMUTABLE STRICT;
138
139CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
140  AS $$
141DECLARE
142  o TEXT;
143BEGIN
144  o := gettokenstring(transliteration(name));
145  RETURN trim(substr(o,1,length(o)));
146END;
147$$
148LANGUAGE 'plpgsql' IMMUTABLE;
149
150CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
151  RETURNS INTEGER
152  AS $$
153DECLARE
154  lookup_token TEXT;
155  return_word_id INTEGER;
156BEGIN
157  lookup_token := trim(lookup_word);
158  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
159  IF return_word_id IS NULL THEN
160    return_word_id := nextval('seq_word');
161    INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
162  END IF;
163  RETURN return_word_id;
164END;
165$$
166LANGUAGE plpgsql;
167
168CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
169  RETURNS INTEGER
170  AS $$
171DECLARE
172  lookup_token TEXT;
173  return_word_id INTEGER;
174BEGIN
175  lookup_token := ' '||trim(lookup_word);
176  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
177  IF return_word_id IS NULL THEN
178    return_word_id := nextval('seq_word');
179    INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
180  END IF;
181  RETURN return_word_id;
182END;
183$$
184LANGUAGE plpgsql;
185
186CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
187  RETURNS INTEGER
188  AS $$
189DECLARE
190  lookup_token TEXT;
191  return_word_id INTEGER;
192BEGIN
193  lookup_token := ' '||trim(lookup_word);
194  SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
195  IF return_word_id IS NULL THEN
196    return_word_id := nextval('seq_word');
197    INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
198  END IF;
199  RETURN return_word_id;
200END;
201$$
202LANGUAGE plpgsql;
203
204CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
205  RETURNS INTEGER
206  AS $$
207DECLARE
208  lookup_token TEXT;
209  return_word_id INTEGER;
210BEGIN
211  lookup_token := ' '||trim(lookup_word);
212  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
213  IF return_word_id IS NULL THEN
214    return_word_id := nextval('seq_word');
215    INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
216  END IF;
217  RETURN return_word_id;
218END;
219$$
220LANGUAGE plpgsql;
221
222CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
223  RETURNS INTEGER
224  AS $$
225DECLARE
226  lookup_token TEXT;
227  return_word_id INTEGER;
228BEGIN
229  lookup_token := lookup_class||'='||lookup_type;
230  SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
231  IF return_word_id IS NULL THEN
232    return_word_id := nextval('seq_word');
233    INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
234  END IF;
235  RETURN return_word_id;
236END;
237$$
238LANGUAGE plpgsql;
239
240CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
241  RETURNS INTEGER
242  AS $$
243DECLARE
244  lookup_token TEXT;
245  return_word_id INTEGER;
246BEGIN
247  lookup_token := lookup_class||'='||lookup_type;
248  SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
249  RETURN return_word_id;
250END;
251$$
252LANGUAGE plpgsql;
253
254CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
255  RETURNS INTEGER
256  AS $$
257DECLARE
258  lookup_token TEXT;
259  return_word_id INTEGER;
260BEGIN
261  lookup_token := ' '||trim(lookup_word);
262  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
263  IF return_word_id IS NULL THEN
264    return_word_id := nextval('seq_word');
265    INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null, op);
266  END IF;
267  RETURN return_word_id;
268END;
269$$
270LANGUAGE plpgsql;
271
272CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
273  RETURNS INTEGER
274  AS $$
275DECLARE
276  lookup_token TEXT;
277  nospace_lookup_token TEXT;
278  return_word_id INTEGER;
279BEGIN
280  lookup_token := ' '||trim(lookup_word);
281  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
282  IF return_word_id IS NULL THEN
283    return_word_id := nextval('seq_word');
284    INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
285--    nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
286--    IF ' '||nospace_lookup_token != lookup_token THEN
287--      INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
288--    END IF;
289  END IF;
290  RETURN return_word_id;
291END;
292$$
293LANGUAGE plpgsql;
294
295CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
296  RETURNS INTEGER
297  AS $$
298DECLARE
299BEGIN
300  RETURN getorcreate_name_id(lookup_word, '');
301END;
302$$
303LANGUAGE plpgsql;
304
305CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
306  RETURNS INTEGER
307  AS $$
308DECLARE
309  lookup_token TEXT;
310  return_word_id INTEGER;
311BEGIN
312  lookup_token := trim(lookup_word);
313  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
314  RETURN return_word_id;
315END;
316$$
317LANGUAGE plpgsql IMMUTABLE;
318
319CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
320  RETURNS INTEGER
321  AS $$
322DECLARE
323  lookup_token TEXT;
324  return_word_id INTEGER;
325BEGIN
326  lookup_token := ' '||trim(lookup_word);
327  SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
328  RETURN return_word_id;
329END;
330$$
331LANGUAGE plpgsql IMMUTABLE;
332
333CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
334  RETURNS INTEGER[]
335  AS $$
336DECLARE
337  i INTEGER;
338  r INTEGER[];
339BEGIN
340  IF array_upper(a, 1) IS NULL THEN
341    RETURN b;
342  END IF;
343  IF array_upper(b, 1) IS NULL THEN
344    RETURN a;
345  END IF;
346  r := a;
347  FOR i IN 1..array_upper(b, 1) LOOP 
348    IF NOT (ARRAY[b[i]] && r) THEN
349      r := r || b[i];
350    END IF;
351  END LOOP;
352  RETURN r;
353END;
354$$
355LANGUAGE plpgsql IMMUTABLE;
356
357CREATE OR REPLACE FUNCTION add_keywords(a keyvalue[], b keyvalue[]) RETURNS keyvalue[]
358  AS $$
359DECLARE
360  i INTEGER;
361  j INTEGER;
362  f BOOLEAN;
363  r keyvalue[];
364BEGIN
365  IF array_upper(a, 1) IS NULL THEN
366    RETURN b;
367  END IF;
368  IF array_upper(b, 1) IS NULL THEN
369    RETURN a;
370  END IF;
371  r := a;
372  FOR i IN 1..array_upper(b, 1) LOOP 
373    f := false;
374    FOR j IN 1..array_upper(a, 1) LOOP 
375      IF (a[j].key = b[i].key) THEN
376        f := true;
377      END IF;
378    END LOOP;
379    IF NOT f THEN
380      r := r || b[i];
381    END IF;
382  END LOOP;
383  RETURN r;
384END;
385$$
386LANGUAGE plpgsql IMMUTABLE;
387
388CREATE OR REPLACE FUNCTION make_keywords(src keyvalue[]) RETURNS INTEGER[]
389  AS $$
390DECLARE
391  result INTEGER[];
392  s TEXT;
393  w INTEGER;
394  words TEXT[];
395  i INTEGER;
396  j INTEGER;
397BEGIN
398  result := '{}'::INTEGER[];
399
400  IF NOT array_upper(src, 1) IS NULL THEN
401
402    FOR i IN 1..array_upper(src, 1) LOOP
403
404      s := make_standard_name(src[i].value);
405
406      w := getorcreate_name_id(s, src[i].value);
407      IF NOT (ARRAY[w] && result) THEN
408        result := result || w;
409      END IF;
410
411      words := string_to_array(s, ' ');
412      IF array_upper(words, 1) IS NOT NULL THEN
413        FOR j IN 1..array_upper(words, 1) LOOP
414          IF (words[j] != '') THEN
415            w = getorcreate_word_id(words[j]);
416            IF NOT (ARRAY[w] && result) THEN
417              result := result || w;
418            END IF;
419          END IF;
420        END LOOP;
421      END IF;
422
423      words := regexp_split_to_array(src[i].value, E'[,;()]');
424      IF array_upper(words, 1) != 1 THEN
425        FOR j IN 1..array_upper(words, 1) LOOP
426          s := make_standard_name(words[j]);
427          IF s != '' THEN
428            w := getorcreate_word_id(s);
429            IF NOT (ARRAY[w] && result) THEN
430              result := result || w;
431            END IF;
432          END IF;
433        END LOOP;
434      END IF;
435
436      s := regexp_replace(src[i].value, '市$', '');
437      IF s != src[i].value THEN
438        s := make_standard_name(s);
439        IF s != '' THEN
440          w := getorcreate_name_id(s, src[i].value);
441          IF NOT (ARRAY[w] && result) THEN
442            result := result || w;
443          END IF;
444        END IF;
445      END IF;
446
447    END LOOP;
448  END IF;
449  RETURN result;
450END;
451$$
452LANGUAGE plpgsql IMMUTABLE;
453
454CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
455  AS $$
456DECLARE
457  result INTEGER[];
458  s TEXT;
459  w INTEGER;
460  words TEXT[];
461  i INTEGER;
462  j INTEGER;
463BEGIN
464  result := '{}'::INTEGER[];
465
466  s := make_standard_name(src);
467  w := getorcreate_name_id(s);
468
469  IF NOT (ARRAY[w] && result) THEN
470    result := result || w;
471  END IF;
472
473  words := string_to_array(s, ' ');
474  IF array_upper(words, 1) IS NOT NULL THEN
475    FOR j IN 1..array_upper(words, 1) LOOP
476      IF (words[j] != '') THEN
477        w = getorcreate_word_id(words[j]);
478        IF NOT (ARRAY[w] && result) THEN
479          result := result || w;
480        END IF;
481      END IF;
482    END LOOP;
483  END IF;
484
485  RETURN result;
486END;
487$$
488LANGUAGE plpgsql IMMUTABLE;
489
490CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
491  AS $$
492DECLARE
493  idxword integer;
494  idxscores integer;
495  result integer;
496BEGIN
497  IF (wordscores is null OR words is null) THEN
498    RETURN 0;
499  END IF;
500
501  result := 0;
502  FOR idxword in 1 .. array_upper(words, 1) LOOP
503    FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
504      IF wordscores[idxscores].word = words[idxword] THEN
505        result := result + wordscores[idxscores].score;
506      END IF;
507    END LOOP;
508  END LOOP;
509
510  RETURN result;
511END;
512$$
513LANGUAGE plpgsql IMMUTABLE;
514
515CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
516  AS $$
517DECLARE
518  place_centre GEOMETRY;
519  nearcountry RECORD;
520BEGIN
521  place_centre := ST_Centroid(place);
522
523  -- Try for a OSM polygon first
524  FOR nearcountry IN select country_code from location_area where st_contains(area, place_centre) limit 1
525  LOOP
526    RETURN nearcountry.country_code;
527  END LOOP;
528
529  -- Try for an OSM polygon first, grid is faster
530  FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
531  LOOP
532    RETURN nearcountry.country_code;
533  END LOOP;
534
535  -- Natural earth data (first fallback)
536--  FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
537--  LOOP
538--    RETURN nearcountry.country_code;
539--  END LOOP;
540
541  -- WorldBoundaries data (second fallback - think there might be something broken in this data)
542  FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
543  LOOP
544    RETURN nearcountry.country_code;
545  END LOOP;
546
547  -- Still not in a country - try nearest within ~12 miles of a country
548  FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
549    order by st_distance(geometry, place) limit 1
550  LOOP
551    RETURN nearcountry.country_code;
552  END LOOP;
553
554  RETURN NULL;
555END;
556$$
557LANGUAGE plpgsql IMMUTABLE;
558
559CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
560  AS $$
561DECLARE
562  nearcountry RECORD;
563BEGIN
564  FOR nearcountry IN select distinct country_default_language_code from country where country_code = search_country_code limit 1
565  LOOP
566    RETURN lower(nearcountry.country_default_language_code);
567  END LOOP;
568  RETURN NULL;
569END;
570$$
571LANGUAGE plpgsql IMMUTABLE;
572
573CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
574  AS $$
575DECLARE
576BEGIN
577  DELETE FROM location_area where place_id = OLD_place_id;
578  DELETE FROM location_point where place_id = OLD_place_id;
579  DELETE FROM location_point_0 where place_id = OLD_place_id;
580  DELETE FROM location_point_1 where place_id = OLD_place_id;
581  DELETE FROM location_point_2 where place_id = OLD_place_id;
582  DELETE FROM location_point_3 where place_id = OLD_place_id;
583  DELETE FROM location_point_4 where place_id = OLD_place_id;
584  DELETE FROM location_point_5 where place_id = OLD_place_id;
585  DELETE FROM location_point_6 where place_id = OLD_place_id;
586  DELETE FROM location_point_7 where place_id = OLD_place_id;
587  DELETE FROM location_point_8 where place_id = OLD_place_id;
588  DELETE FROM location_point_9 where place_id = OLD_place_id;
589  DELETE FROM location_point_10 where place_id = OLD_place_id;
590  DELETE FROM location_point_11 where place_id = OLD_place_id;
591  DELETE FROM location_point_12 where place_id = OLD_place_id;
592  DELETE FROM location_point_13 where place_id = OLD_place_id;
593  DELETE FROM location_point_14 where place_id = OLD_place_id;
594  DELETE FROM location_point_15 where place_id = OLD_place_id;
595  DELETE FROM location_point_16 where place_id = OLD_place_id;
596  DELETE FROM location_point_17 where place_id = OLD_place_id;
597  DELETE FROM location_point_18 where place_id = OLD_place_id;
598  DELETE FROM location_point_19 where place_id = OLD_place_id;
599  DELETE FROM location_point_20 where place_id = OLD_place_id;
600  DELETE FROM location_point_21 where place_id = OLD_place_id;
601  DELETE FROM location_point_22 where place_id = OLD_place_id;
602  DELETE FROM location_point_23 where place_id = OLD_place_id;
603  DELETE FROM location_point_24 where place_id = OLD_place_id;
604  DELETE FROM location_point_25 where place_id = OLD_place_id;
605  DELETE FROM location_point_26 where place_id = OLD_place_id;
606  RETURN true;
607END;
608$$
609LANGUAGE plpgsql;
610
611CREATE OR REPLACE FUNCTION add_location(
612    place_id BIGINT,
613    place_country_code varchar(2),
614    name keyvalue[],
615    rank_search INTEGER,
616    rank_address INTEGER,
617    geometry GEOMETRY
618  )
619  RETURNS BOOLEAN
620  AS $$
621DECLARE
622  keywords INTEGER[];
623  country_code VARCHAR(2);
624  locationid INTEGER;
625  isarea BOOLEAN;
626  xmin INTEGER;
627  ymin INTEGER;
628  xmax INTEGER;
629  ymax INTEGER;
630  lon INTEGER;
631  lat INTEGER;
632  secgeo GEOMETRY;
633BEGIN
634
635  -- Allocate all tokens ids - prevents multi-processor race condition later on at cost of slowing down import
636  keywords := make_keywords(name);
637
638  -- 26 = street/highway
639  IF rank_search < 26 THEN
640    IF place_country_code IS NULL THEN
641      country_code := get_country_code(geometry);
642    END IF;
643    country_code := lower(place_country_code);
644
645    isarea := false;
646    IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
647
648      isArea := true;
649
650      xmin := floor(st_xmin(geometry));
651      xmax := ceil(st_xmax(geometry));
652      ymin := floor(st_ymin(geometry));
653      ymax := ceil(st_ymax(geometry));
654
655      IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
656        INSERT INTO location_area values (place_id, country_code, name, keywords,
657          rank_search, rank_address, ST_Centroid(geometry), geometry);
658      ELSE
659        FOR lon IN xmin..(xmax-1) LOOP
660          FOR lat IN ymin..(ymax-1) LOOP
661            secgeo := st_intersection(geometry, ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326));
662            IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
663              INSERT INTO location_area values (place_id, country_code, name, keywords,
664                rank_search, rank_address, ST_Centroid(geometry),
665                st_intersection(geometry, ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326))
666                );
667            END IF;
668          END LOOP;
669        END LOOP;
670      END IF;
671
672    END IF;
673
674    INSERT INTO location_point values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
675    IF not isarea THEN
676    IF rank_search < 26 THEN
677      INSERT INTO location_point_26 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
678    IF rank_search < 25 THEN
679      INSERT INTO location_point_25 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
680    IF rank_search < 24 THEN
681      INSERT INTO location_point_24 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
682    IF rank_search < 23 THEN
683      INSERT INTO location_point_23 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
684    IF rank_search < 22 THEN
685      INSERT INTO location_point_22 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
686    IF rank_search < 21 THEN
687      INSERT INTO location_point_21 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
688    IF rank_search < 20 THEN
689      INSERT INTO location_point_20 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
690    IF rank_search < 19 THEN
691      INSERT INTO location_point_19 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
692    IF rank_search < 18 THEN
693      INSERT INTO location_point_18 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
694    IF rank_search < 17 THEN
695      INSERT INTO location_point_17 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
696    IF rank_search < 16 THEN
697      INSERT INTO location_point_16 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
698    IF rank_search < 15 THEN
699      INSERT INTO location_point_15 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
700    IF rank_search < 14 THEN
701      INSERT INTO location_point_14 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
702    IF rank_search < 13 THEN
703      INSERT INTO location_point_13 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
704    IF rank_search < 12 THEN
705      INSERT INTO location_point_12 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
706    IF rank_search < 11 THEN
707      INSERT INTO location_point_11 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
708    IF rank_search < 10 THEN
709      INSERT INTO location_point_10 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
710    IF rank_search < 9 THEN
711      INSERT INTO location_point_9 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
712    IF rank_search < 8 THEN
713      INSERT INTO location_point_8 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
714    IF rank_search < 7 THEN
715      INSERT INTO location_point_7 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
716    IF rank_search < 6 THEN
717      INSERT INTO location_point_6 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
718    IF rank_search < 5 THEN
719      INSERT INTO location_point_5 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
720    IF rank_search < 4 THEN
721      INSERT INTO location_point_4 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
722    IF rank_search < 3 THEN
723      INSERT INTO location_point_3 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
724    IF rank_search < 2 THEN
725      INSERT INTO location_point_2 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
726    IF rank_search < 1 THEN
727      INSERT INTO location_point_1 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
728    END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;
729    END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;
730    END IF;END IF;END IF;END IF;END IF;END IF;END IF;
731    RETURN true;
732  END IF;
733  RETURN false;
734END;
735$$
736LANGUAGE plpgsql;
737
738CREATE OR REPLACE FUNCTION update_location(
739    place_id BIGINT,
740    place_country_code varchar(2),
741    name keyvalue[],
742    rank_search INTEGER,
743    rank_address INTEGER,
744    geometry GEOMETRY
745  )
746  RETURNS BOOLEAN
747  AS $$
748DECLARE
749  b BOOLEAN;
750BEGIN
751  b := delete_location(place_id);
752  RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
753END;
754$$
755LANGUAGE plpgsql;
756
757CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
758  RETURNS BOOLEAN
759  AS $$
760DECLARE
761  childplace RECORD;
762BEGIN
763
764  IF #to_add = 0 THEN
765    RETURN true;
766  END IF;
767
768  -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
769  FOR childplace IN select * from search_name,place_addressline
770    where  address_place_id = parent_place_id
771      and search_name.place_id = place_addressline.place_id
772  LOOP
773    delete from search_name where place_id = childplace.place_id;
774    childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
775    IF childplace.place_id = parent_place_id THEN
776      childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
777    END IF;
778    insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
779      values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
780        childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
781  END LOOP;
782
783  RETURN true;
784END;
785$$
786LANGUAGE plpgsql;
787
788CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id BIGINT, name keyvalue[]) RETURNS BOOLEAN
789  AS $$
790DECLARE
791  newkeywords INTEGER[];
792  addedkeywords INTEGER[];
793  removedkeywords INTEGER[];
794BEGIN
795
796  -- what has changed?
797  newkeywords := make_keywords(name);
798  select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
799    coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
800    where place_id = OLD_place_id into addedkeywords, removedkeywords;
801
802--  RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
803
804  IF #removedkeywords > 0 THEN
805    -- abort due to tokens removed
806    RETURN false;
807  END IF;
808 
809  IF #addedkeywords > 0 THEN
810    -- short circuit - no changes
811    RETURN true;
812  END IF;
813
814  UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
815  UPDATE location_point set keywords = newkeywords where place_id = OLD_place_id;
816  UPDATE location_point_0 set keywords = newkeywords where place_id = OLD_place_id;
817  UPDATE location_point_1 set keywords = newkeywords where place_id = OLD_place_id;
818  UPDATE location_point_2 set keywords = newkeywords where place_id = OLD_place_id;
819  UPDATE location_point_3 set keywords = newkeywords where place_id = OLD_place_id;
820  UPDATE location_point_4 set keywords = newkeywords where place_id = OLD_place_id;
821  UPDATE location_point_5 set keywords = newkeywords where place_id = OLD_place_id;
822  UPDATE location_point_6 set keywords = newkeywords where place_id = OLD_place_id;
823  UPDATE location_point_7 set keywords = newkeywords where place_id = OLD_place_id;
824  UPDATE location_point_8 set keywords = newkeywords where place_id = OLD_place_id;
825  UPDATE location_point_9 set keywords = newkeywords where place_id = OLD_place_id;
826  UPDATE location_point_10 set keywords = newkeywords where place_id = OLD_place_id;
827  UPDATE location_point_11 set keywords = newkeywords where place_id = OLD_place_id;
828  UPDATE location_point_12 set keywords = newkeywords where place_id = OLD_place_id;
829  UPDATE location_point_13 set keywords = newkeywords where place_id = OLD_place_id;
830  UPDATE location_point_14 set keywords = newkeywords where place_id = OLD_place_id;
831  UPDATE location_point_15 set keywords = newkeywords where place_id = OLD_place_id;
832  UPDATE location_point_16 set keywords = newkeywords where place_id = OLD_place_id;
833  UPDATE location_point_17 set keywords = newkeywords where place_id = OLD_place_id;
834  UPDATE location_point_18 set keywords = newkeywords where place_id = OLD_place_id;
835  UPDATE location_point_19 set keywords = newkeywords where place_id = OLD_place_id;
836  UPDATE location_point_20 set keywords = newkeywords where place_id = OLD_place_id;
837  UPDATE location_point_21 set keywords = newkeywords where place_id = OLD_place_id;
838  UPDATE location_point_22 set keywords = newkeywords where place_id = OLD_place_id;
839  UPDATE location_point_23 set keywords = newkeywords where place_id = OLD_place_id;
840  UPDATE location_point_24 set keywords = newkeywords where place_id = OLD_place_id;
841  UPDATE location_point_25 set keywords = newkeywords where place_id = OLD_place_id;
842  UPDATE location_point_26 set keywords = newkeywords where place_id = OLD_place_id;
843
844  RETURN search_name_add_words(OLD_place_id, addedkeywords);
845END;
846$$
847LANGUAGE plpgsql;
848
849
850CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
851  AS $$
852DECLARE
853 
854  newpoints INTEGER;
855  waynodes integer[];
856  nodeid INTEGER;
857  prevnode RECORD;
858  nextnode RECORD;
859  startnumber INTEGER;
860  endnumber INTEGER;
861  stepsize INTEGER;
862  orginalstartnumber INTEGER;
863  originalnumberrange INTEGER;
864  housenum INTEGER;
865  linegeo GEOMETRY;
866  search_place_id INTEGER;
867
868  havefirstpoint BOOLEAN;
869  linestr TEXT;
870BEGIN
871  newpoints := 0;
872  IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
873
874    select nodes from planet_osm_ways where id = wayid INTO waynodes;
875--RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
876    IF array_upper(waynodes, 1) IS NOT NULL THEN
877
878      havefirstpoint := false;
879
880      FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
881
882        select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::bigint and type = 'house' INTO search_place_id;
883        IF search_place_id IS NULL THEN
884          -- null record of right type
885          select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::bigint and type = 'house' limit 1 INTO nextnode;
886          select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
887        ELSE
888          select * from placex where place_id = search_place_id INTO nextnode;
889        END IF;
890
891--RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
892     
893        IF havefirstpoint THEN
894
895          -- add point to the line string
896          linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
897          endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
898
899          IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
900
901--RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
902
903            IF startnumber != endnumber THEN
904
905              linestr := linestr || ')';
906--RAISE WARNING 'linestr %',linestr;
907              linegeo := ST_GeomFromText(linestr,4326);
908              linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
909              IF (startnumber > endnumber) THEN
910                housenum := endnumber;
911                endnumber := startnumber;
912                startnumber := housenum;
913                linegeo := ST_Reverse(linegeo);
914              END IF;
915              orginalstartnumber := startnumber;
916              originalnumberrange := endnumber - startnumber;
917
918-- Too much broken data worldwide for this test to be worth using
919--              IF originalnumberrange > 500 THEN
920--                RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
921--              END IF;
922
923              IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
924                startnumber := startnumber + 1;
925                stepsize := 2;
926              ELSE
927                IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
928                  startnumber := startnumber + 2;
929                  stepsize := 2;
930                ELSE -- everything else assumed to be 'all'
931                  startnumber := startnumber + 1;
932                  stepsize := 1;
933                END IF;
934              END IF;
935              endnumber := endnumber - 1;
936              delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
937              FOR housenum IN startnumber..endnumber BY stepsize LOOP
938                -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
939                -- ideally postcodes should move up to the way
940                insert into placex values (null,'N',prevnode.osm_id,prevnode.class,prevnode.type,NULL,prevnode.admin_level,housenum,prevnode.street,prevnode.isin,null,prevnode.country_code,prevnode.street_place_id,prevnode.rank_address,prevnode.rank_search,false,ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
941                newpoints := newpoints + 1;
942--RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
943              END LOOP;
944            END IF;
945            havefirstpoint := false;
946          END IF;
947        END IF;
948
949        IF NOT havefirstpoint THEN
950          startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
951          IF startnumber IS NOT NULL AND startnumber > 0 THEN
952            havefirstpoint := true;
953            linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
954            prevnode := nextnode;
955          END IF;
956--RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
957        END IF;
958      END LOOP;
959    END IF;
960  END IF;
961
962--RAISE WARNING 'interpolation points % ',newpoints;
963
964  RETURN newpoints;
965END;
966$$
967LANGUAGE plpgsql;
968
969CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
970  AS $$
971DECLARE
972  i INTEGER;
973  postcode TEXT;
974  result BOOLEAN;
975  country_code VARCHAR(2);
976  diameter FLOAT;
977BEGIN
978--  RAISE WARNING '%',NEW.osm_id;
979--  RAISE WARNING '%',NEW.osm_id;
980
981  -- just block these
982  IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
983    RETURN null;
984  END IF;
985  IF NEW.class in ('landuse','natural') and NEW.name is null THEN
986    RETURN null;
987  END IF;
988
989--  RAISE WARNING '%',NEW.osm_id;
990  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 
991    -- block all invalid geometary - just not worth the risk.  seg faults are causing serious problems.
992    RETURN NULL;
993
994    -- Dead code
995    IF NEW.osm_type = 'R' THEN
996      -- invalid multipolygons can crash postgis, don't even bother to try!
997      RETURN NULL;
998    END IF;
999    NEW.geometry := ST_buffer(NEW.geometry,0);
1000    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 
1001      RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
1002      RETURN NULL;
1003    END IF;
1004  END IF;
1005
1006  NEW.place_id := nextval('seq_place');
1007  NEW.indexed := false;
1008  NEW.country_code := lower(NEW.country_code);
1009
1010  IF NEW.admin_level > 15 THEN
1011    NEW.admin_level := 15;
1012  END IF;
1013
1014  IF NEW.housenumber IS NOT NULL THEN
1015    i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1016  END IF;
1017
1018  IF NEW.osm_type = 'X' THEN
1019    -- E'X'ternal records should already be in the right format so do nothing
1020  ELSE
1021    NEW.rank_search := 30;
1022    NEW.rank_address := NEW.rank_search;
1023
1024    -- By doing in postgres we have the country available to us - currently only used for postcode
1025    IF NEW.class = 'place' THEN
1026      IF NEW.type in ('continent') THEN
1027        NEW.rank_search := 2;
1028        NEW.rank_address := NEW.rank_search;
1029      ELSEIF NEW.type in ('sea') THEN
1030        NEW.rank_search := 2;
1031        NEW.rank_address := 0;
1032      ELSEIF NEW.type in ('country') THEN
1033        NEW.rank_search := 4;
1034        NEW.rank_address := NEW.rank_search;
1035      ELSEIF NEW.type in ('state') THEN
1036        NEW.rank_search := 8;
1037        NEW.rank_address := NEW.rank_search;
1038      ELSEIF NEW.type in ('region') THEN
1039        NEW.rank_search := 10;
1040        NEW.rank_address := NEW.rank_search;
1041      ELSEIF NEW.type in ('county') THEN
1042        NEW.rank_search := 12;
1043        NEW.rank_address := NEW.rank_search;
1044      ELSEIF NEW.type in ('city') THEN
1045        NEW.rank_search := 16;
1046        NEW.rank_address := NEW.rank_search;
1047      ELSEIF NEW.type in ('island') THEN
1048        NEW.rank_search := 17;
1049        NEW.rank_address := 0;
1050      ELSEIF NEW.type in ('town') THEN
1051        NEW.rank_search := 17;
1052        NEW.rank_address := NEW.rank_search;
1053      ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1054        NEW.rank_search := 18;
1055        NEW.rank_address := 17;
1056      ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1057        NEW.rank_search := 18;
1058        NEW.rank_address := 17;
1059      ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1060        NEW.rank_search := 17;
1061        NEW.rank_address := 18;
1062      ELSEIF NEW.type in ('moor') THEN
1063        NEW.rank_search := 17;
1064        NEW.rank_address := 0;
1065      ELSEIF NEW.type in ('national_park') THEN
1066        NEW.rank_search := 18;
1067        NEW.rank_address := 18;
1068      ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1069        NEW.rank_search := 20;
1070        NEW.rank_address := NEW.rank_search;
1071      ELSEIF NEW.type in ('farm','locality','islet') THEN
1072        NEW.rank_search := 20;
1073        NEW.rank_address := 0;
1074      ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1075        NEW.rank_search := 22;
1076        NEW.rank_address := 22;
1077      ELSEIF NEW.type in ('postcode') THEN
1078
1079        -- Postcode processing is very country dependant
1080        IF NEW.country_code IS NULL THEN
1081          NEW.country_code := get_country_code(NEW.geometry);
1082        END IF;
1083
1084        NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1085
1086        IF NEW.country_code = 'gb' THEN
1087
1088          IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1089            NEW.rank_search := 25;
1090            NEW.rank_address := 5;
1091            NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1092          ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1093            NEW.rank_search := 23;
1094            NEW.rank_address := 5;
1095            NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1096          ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1097            NEW.rank_search := 21;
1098            NEW.rank_address := 5;
1099            NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1100          END IF;
1101
1102        ELSEIF NEW.country_code = 'de' THEN
1103
1104          IF NEW.postcode ~ '^([0-9]{5})$' THEN
1105            NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1106            NEW.rank_search := 21;
1107            NEW.rank_address := 11;
1108          END IF;
1109
1110        ELSE
1111          -- Guess at the postcode format and coverage (!)
1112          IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1113            NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1114            NEW.rank_search := 21;
1115            NEW.rank_address := 11;
1116          ELSE
1117            -- Does it look splitable into and area and local code?
1118            postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1119
1120            IF postcode IS NOT NULL THEN
1121
1122              -- TODO: insert new line into location instead
1123              --result := add_location(NEW.place_id,NEW.country_code,ARRAY[ROW('ref',postcode)::keyvalue],21,11,NEW.geometry);
1124
1125              NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1126              NEW.rank_search := 25;
1127              NEW.rank_address := 11;
1128            ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1129              NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1130              NEW.rank_search := 21;
1131              NEW.rank_address := 11;
1132            END IF;
1133          END IF;
1134        END IF;
1135
1136      ELSEIF NEW.type in ('airport','street') THEN
1137        NEW.rank_search := 26;
1138        NEW.rank_address := NEW.rank_search;
1139      ELSEIF NEW.type in ('house','building') THEN
1140        NEW.rank_search := 28;
1141        NEW.rank_address := NEW.rank_search;
1142      ELSEIF NEW.type in ('houses') THEN
1143        -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1144        -- insert new point into place for each derived building
1145        --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1146      END IF;
1147
1148    ELSEIF NEW.class = 'boundary' THEN
1149      IF NEW.country_code is null THEN
1150        NEW.country_code := get_country_code(NEW.geometry);
1151      END IF;
1152      NEW.rank_search := NEW.admin_level * 2;
1153      NEW.rank_address := NEW.rank_search;
1154    ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1155      NEW.rank_search := 22;
1156      NEW.rank_address := NEW.rank_search;
1157    -- any feature more than 5 square miles is probably worth indexing
1158    ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1159      NEW.rank_search := 22;
1160      NEW.rank_address := NEW.rank_search;
1161    ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1162           NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1163      RETURN NULL;
1164    ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1165      RETURN NULL;
1166    ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1167      RETURN NULL;
1168    ELSEIF NEW.class = 'waterway' THEN
1169      NEW.rank_address := 17;
1170    ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1171      NEW.rank_search := 27;
1172      NEW.rank_address := NEW.rank_search;
1173    ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1174      NEW.rank_search := 26;
1175      NEW.rank_address := NEW.rank_search;
1176    ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1177      NEW.rank_search := 4;
1178      NEW.rank_address := NEW.rank_search;
1179    ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1180      RETURN NULL;
1181    ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1182      NEW.rank_search := 18;
1183      NEW.rank_address := 0;
1184    END IF;
1185
1186  END IF;
1187
1188  IF NEW.rank_search > 30 THEN
1189    NEW.rank_search := 30;
1190  END IF;
1191
1192  IF NEW.rank_address > 30 THEN
1193    NEW.rank_address := 30;
1194  END IF;
1195
1196-- Block import below rank 22
1197--  IF NEW.rank_search > 22 THEN
1198--    RETURN NULL;
1199--  END IF;
1200
1201  IF array_upper(NEW.name, 1) is not null THEN
1202    result := add_location(NEW.place_id,NEW.country_code,NEW.name,NEW.rank_search,NEW.rank_address,NEW.geometry);
1203  END IF;
1204
1205  --RETURN NEW;
1206  -- The following is not needed until doing diff updates, and slows the main index process down
1207
1208  IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1209    -- Performance: We just can't handle re-indexing for country level changes
1210    IF st_area(NEW.geometry) < 1 THEN
1211      -- mark items within the geometry for re-indexing
1212--    RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1213-- work around bug in postgis
1214      update placex set indexed = false where indexed and (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1215       AND rank_search > NEW.rank_search and ST_geometrytype(placex.geometry) = 'ST_Point';
1216      update placex set indexed = false where indexed and (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1217       AND rank_search > NEW.rank_search and ST_geometrytype(placex.geometry) != 'ST_Point';
1218    END IF;
1219  ELSE
1220    -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1221    diameter := 0;
1222    -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1223    IF NEW.type='postcode' THEN
1224      diameter := 0.001;
1225    ELSEIF NEW.rank_search < 16 THEN
1226      diameter := 0;
1227    ELSEIF NEW.rank_search < 18 THEN
1228      diameter := 0.1;
1229    ELSEIF NEW.rank_search < 20 THEN
1230      diameter := 0.05;
1231    ELSEIF NEW.rank_search = 21 THEN
1232      diameter := 0.001;
1233    ELSEIF NEW.rank_search < 24 THEN
1234      diameter := 0.02;
1235    ELSEIF NEW.rank_search < 26 THEN
1236      diameter := 0.002; -- 100 to 200 meters
1237    ELSEIF NEW.rank_search < 28 THEN
1238      diameter := 0.001; -- 50 to 100 meters
1239    END IF;
1240    IF diameter > 0 THEN
1241--      RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1242      update placex set indexed = false where indexed and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1243    END IF;
1244
1245  END IF;
1246
1247--  IF NEW.rank_search < 26 THEN
1248--    RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1249--  END IF;
1250
1251  RETURN NEW;
1252
1253END;
1254$$
1255LANGUAGE plpgsql;
1256
1257CREATE OR REPLACE FUNCTION placex_update() RETURNS
1258TRIGGER
1259  AS $$
1260DECLARE
1261
1262  place_centroid GEOMETRY;
1263  place_geometry_text TEXT;
1264
1265  search_maxdistance FLOAT[];
1266  search_mindistance FLOAT[];
1267  address_havelevel BOOLEAN[];
1268--  search_scores wordscore[];
1269--  search_scores_pos INTEGER;
1270  search_country_code_conflict BOOLEAN;
1271
1272  i INTEGER;
1273  iMax FLOAT;
1274  location RECORD;
1275  relation RECORD;
1276  search_diameter FLOAT;
1277  search_prevdiameter FLOAT;
1278  search_maxrank INTEGER;
1279  address_maxrank INTEGER;
1280  address_street_word_id INTEGER;
1281  street_place_id_count INTEGER;
1282  isin TEXT[];
1283  tagpairid INTEGER;
1284
1285  bPointCountryCode BOOLEAN;
1286
1287  name_vector INTEGER[];
1288  nameaddress_vector INTEGER[];
1289
1290  result BOOLEAN;
1291
1292BEGIN
1293
1294--  RAISE WARNING '%',NEW.place_id;
1295--RAISE WARNING '%', NEW;
1296
1297  IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1298    -- Silently do nothing
1299    RETURN NEW;
1300  END IF;
1301
1302  NEW.country_code := lower(NEW.country_code);
1303
1304  IF NEW.indexed and NOT OLD.indexed THEN
1305
1306    IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1307      i := create_interpolation(NEW.osm_id, NEW.housenumber);
1308      RETURN NEW;
1309    END IF;
1310
1311--RAISE WARNING 'PROCESSING: % %', NEW.place_id, NEW.name;
1312
1313    search_country_code_conflict := false;
1314
1315    DELETE FROM search_name WHERE place_id = NEW.place_id;
1316--RAISE WARNING 'x1';
1317    DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1318--RAISE WARNING 'x2';
1319    DELETE FROM place_boundingbox where place_id = NEW.place_id;
1320
1321    -- Adding ourselves to the list simplifies address calculations later
1322    INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1323--RAISE WARNING 'x3';
1324
1325    -- What level are we searching from
1326    search_maxrank := NEW.rank_search;
1327
1328    -- Default max/min distances to look for a location
1329    FOR i IN 1..28 LOOP
1330      search_maxdistance[i] := 1;
1331      search_mindistance[i] := 0.0;
1332      address_havelevel[i] := false;
1333    END LOOP;
1334    -- Minimum size to search, can be larger but don't let it shink below this
1335    search_mindistance[14] := 0.2;
1336    search_mindistance[15] := 0.1;
1337    search_mindistance[16] := 0.05;
1338    search_mindistance[17] := 0.03;
1339    search_mindistance[18] := 0.015;
1340    search_mindistance[19] := 0.008;
1341    search_mindistance[20] := 0.006;
1342    search_mindistance[21] := 0.004;
1343    search_mindistance[22] := 0.003;
1344    search_mindistance[23] := 0.002;
1345    search_mindistance[24] := 0.002;
1346    search_mindistance[25] := 0.001;
1347    search_mindistance[26] := 0.001;
1348
1349    search_maxdistance[14] := 1;
1350    search_maxdistance[15] := 0.5;
1351    search_maxdistance[16] := 0.15;
1352    search_maxdistance[17] := 0.05;
1353    search_maxdistance[18] := 0.02;
1354    search_maxdistance[19] := 0.02;
1355    search_maxdistance[20] := 0.02;
1356    search_maxdistance[21] := 0.02;
1357    search_maxdistance[22] := 0.02;
1358    search_maxdistance[23] := 0.02;
1359    search_maxdistance[24] := 0.02;
1360    search_maxdistance[25] := 0.02;
1361    search_maxdistance[26] := 0.02;
1362
1363    -- Speed up searches - just use the centroid of the feature
1364    -- cheaper but less acurate
1365    place_centroid := ST_Centroid(NEW.geometry);
1366    place_geometry_text := 'ST_GeomFromText('''||ST_AsText(NEW.geometry)||''','||ST_SRID(NEW.geometry)||')';
1367
1368    -- copy the building number to the name
1369    -- done here rather than on insert to avoid initial indexing
1370    -- TODO: This might be a silly thing to do
1371    --IF (NEW.name IS NULL OR array_upper(NEW.name,1) IS NULL) AND NEW.housenumber IS NOT NULL THEN
1372    --  NEW.name := ARRAY[ROW('ref',NEW.housenumber)::keyvalue];
1373    --END IF;
1374
1375    --Temp hack to prevent need to re-index
1376    IF NEW.name::text = '{"(ref,'||NEW.housenumber||')"}' THEN
1377      NEW.name := NULL;
1378    END IF;
1379
1380    --IF (NEW.name IS NULL OR array_upper(NEW.name,1) IS NULL) AND NEW.type IS NOT NULL THEN
1381    --  NEW.name := ARRAY[ROW('type',NEW.type)::keyvalue];
1382    --END IF;
1383
1384    -- Initialise the name and address vectors using our name
1385    name_vector := make_keywords(NEW.name);
1386    nameaddress_vector := name_vector;
1387
1388    -- some tag combinations add a special id for search
1389    tagpairid := get_tagpair(NEW.class,NEW.type);
1390    IF tagpairid IS NOT NULL THEN
1391      name_vector := name_vector + tagpairid;
1392    END IF;
1393
1394--RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1395
1396    -- For low level elements we inherit from our parent road
1397    IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1398
1399--RAISE WARNING 'finding street for %', NEW;
1400
1401      NEW.street_place_id := null;
1402
1403      -- to do that we have to find our parent road
1404      -- Copy data from linked items (points on ways, addr:street links, relations)
1405      -- Note that addr:street links can only be indexed once the street itself is indexed
1406      IF NEW.street_place_id IS NULL AND NEW.osm_type = 'N' THEN
1407
1408        -- Is this node part of a relation?
1409        FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1410        LOOP
1411          -- At the moment we only process one type of relation - associatedStreet
1412          IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1413            FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1414              IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1415--RAISE WARNING 'node in relation %',relation;
1416                SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1417                  and rank_search = 26 INTO NEW.street_place_id;
1418              END IF;
1419            END LOOP;
1420          END IF;
1421        END LOOP;     
1422
1423--RAISE WARNING 'x1';
1424        -- Is this node part of a way?
1425        -- Limit 10 is to work round problem in query plan optimiser
1426        FOR location IN select * from placex where osm_type = 'W'
1427          and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer] limit 10)
1428        LOOP
1429--RAISE WARNING '%', location;
1430          -- Way IS a road then we are on it - that must be our road
1431          IF location.rank_search = 26 AND NEW.street_place_id IS NULL THEN
1432--RAISE WARNING 'node in way that is a street %',location;
1433            NEW.street_place_id := location.place_id;
1434          END IF;
1435
1436          -- Is the WAY part of a relation
1437          FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1438          LOOP
1439            -- At the moment we only process one type of relation - associatedStreet
1440            IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1441              FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1442                IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1443--RAISE WARNING 'node in way that is in a relation %',relation;
1444                  SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1445                    and rank_search = 26 INTO NEW.street_place_id;
1446                END IF;
1447              END LOOP;
1448            END IF;
1449          END LOOP;
1450         
1451          -- If the way contains an explicit name of a street copy it
1452          IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1453--RAISE WARNING 'node in way that has a streetname %',location;
1454            NEW.street := location.street;
1455          END IF;
1456
1457          -- If this way is a street interpolation line then it is probably as good as we are going to get
1458          IF NEW.street_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1459            -- Try and find a way that is close roughly parellel to this line
1460            FOR relation IN SELECT place_id FROM placex
1461              WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1462              ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1463                        ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1464                        ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1465            LOOP
1466--RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1467              NEW.street_place_id := relation.place_id;
1468            END LOOP;
1469          END IF;
1470
1471        END LOOP;
1472               
1473      END IF;
1474
1475--RAISE WARNING 'x2';
1476
1477      IF NEW.street_place_id IS NULL AND NEW.osm_type = 'W' THEN
1478        -- Is this way part of a relation?
1479        FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1480        LOOP
1481          -- At the moment we only process one type of relation - associatedStreet
1482          IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1483            FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1484              IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1485--RAISE WARNING 'way that is in a relation %',relation;
1486                SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1487                  and rank_search = 26 INTO NEW.street_place_id;
1488              END IF;
1489            END LOOP;
1490          END IF;
1491        END LOOP;
1492      END IF;
1493     
1494--RAISE WARNING 'x3';
1495
1496      IF NEW.street_place_id IS NULL AND NEW.street IS NOT NULL THEN
1497        address_street_word_id := get_name_id(make_standard_name(NEW.street));
1498--RAISE WARNING 'street: % %', NEW.street, address_street_word_id;
1499        IF address_street_word_id IS NOT NULL THEN
1500          FOR location IN SELECT place_id,ST_distance(NEW.geometry, search_name.centroid) as distance
1501            FROM search_name WHERE search_name.name_vector @> ARRAY[address_street_word_id]
1502            AND ST_DWithin(NEW.geometry, search_name.centroid, 0.01) and search_rank between 22 and 27
1503            ORDER BY ST_distance(NEW.geometry, search_name.centroid) ASC limit 1
1504          LOOP
1505--RAISE WARNING 'streetname found nearby %',location;
1506            NEW.street_place_id := location.place_id;
1507          END LOOP;
1508        END IF;
1509        -- Failed, fall back to nearest - don't just stop
1510        IF NEW.street_place_id IS NULL THEN
1511--RAISE WARNING 'unable to find streetname nearby % %',NEW.street,address_street_word_id;
1512--          RETURN null;
1513        END IF;
1514      END IF;
1515
1516--RAISE WARNING 'x4';
1517
1518      search_diameter := 0.00005;
1519      WHILE NEW.street_place_id IS NULL AND search_diameter < 0.1 LOOP
1520--RAISE WARNING '% %', search_diameter,ST_AsText(ST_Centroid(NEW.geometry));
1521        FOR location IN SELECT place_id FROM placex
1522          WHERE ST_DWithin(place_centroid, placex.geometry, search_diameter) and rank_search between 22 and 27
1523          ORDER BY ST_distance(NEW.geometry, placex.geometry) ASC limit 1
1524        LOOP
1525--RAISE WARNING 'using nearest street,% % %',search_diameter,NEW.street,location;
1526          NEW.street_place_id := location.place_id;
1527        END LOOP;
1528        search_diameter := search_diameter * 2;
1529      END LOOP;
1530
1531--RAISE WARNING 'x6 %',NEW.street_place_id;
1532
1533      -- If we didn't find any road give up, should be VERY rare
1534      IF NEW.street_place_id IS NOT NULL THEN
1535
1536        -- Some unnamed roads won't have been indexed, index now if needed
1537        select count(*) from place_addressline where place_id = NEW.street_place_id INTO street_place_id_count;
1538        IF street_place_id_count = 0 THEN
1539          UPDATE placex set indexed = true where indexed = false and place_id = NEW.street_place_id;
1540        END IF;
1541
1542        -- Add the street to the address as zero distance to force to front of list
1543        INSERT INTO place_addressline VALUES (NEW.place_id, NEW.street_place_id, true, true, 0, 26);
1544        address_havelevel[26] := true;
1545
1546        -- Import address details from parent, reclculating distance in process
1547        INSERT INTO place_addressline select NEW.place_id, x.address_place_id, x.fromarea, x.isaddress, ST_distance(NEW.geometry, placex.geometry), placex.rank_address
1548          from place_addressline as x join placex on (address_place_id = placex.place_id)
1549          where x.place_id = NEW.street_place_id and x.address_place_id != NEW.street_place_id;
1550
1551        -- Get the details of the parent road
1552        select * from search_name where place_id = NEW.street_place_id INTO location;
1553        NEW.country_code := location.country_code;
1554
1555--RAISE WARNING '%', NEW.name;
1556        -- If there is no name it isn't searchable, don't bother to create a search record
1557        IF NEW.name is NULL THEN
1558          return NEW;
1559        END IF;
1560
1561        -- Merge address from parent
1562        nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1563
1564        -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1565        -- Just be happy with inheriting from parent road only
1566        INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_address, NEW.country_code,
1567          name_vector, nameaddress_vector, place_centroid);
1568
1569        return NEW;
1570      END IF;
1571
1572    END IF;
1573
1574--RAISE WARNING '  INDEXING: %',NEW;
1575
1576    -- Process area matches (tend to be better quality)
1577    FOR location IN SELECT
1578      place_id,
1579      name,
1580      keywords,
1581      country_code,
1582      rank_address,
1583      rank_search,
1584      ST_Distance(place_centroid, centroid) as distance
1585      FROM location_area
1586      WHERE ST_Contains(area, place_centroid) and location_area.rank_search < search_maxrank
1587      ORDER BY ST_Distance(place_centroid, centroid) ASC
1588    LOOP
1589
1590--RAISE WARNING '  AREA: % % %',location.keywords,NEW.country_code,location.country_code;
1591
1592      IF NEW.country_code IS NULL THEN
1593        NEW.country_code := location.country_code;
1594      ELSEIF NEW.country_code != location.country_code and location.rank_search > 3 THEN
1595        search_country_code_conflict := true;
1596      END IF;
1597
1598      -- Add it to the list of search terms
1599      nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1600      INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1601      address_havelevel[location.rank_address] := true;
1602
1603    END LOOP;
1604
1605    -- try using the isin value to find parent places
1606    address_maxrank := search_maxrank;
1607    IF NEW.isin IS NOT NULL THEN
1608      -- Doing isin without a country code seems to be dangerous
1609      IF NEW.country_code is null THEN
1610        NEW.country_code := get_country_code(place_centroid);
1611      END IF;
1612      isin := regexp_split_to_array(NEW.isin, E'[;,]');
1613      FOR i IN 1..array_upper(isin, 1) LOOP
1614        address_street_word_id := get_name_id(make_standard_name(isin[i]));
1615        IF address_street_word_id IS NOT NULL THEN
1616--RAISE WARNING '  search: %',address_street_word_id;
1617          FOR location IN SELECT place_id,keywords,rank_search,location_point.country_code,rank_address,
1618            ST_Distance(place_centroid, search_name.centroid) as distance
1619            FROM search_name join location_point using (place_id)
1620            WHERE search_name.name_vector @> ARRAY[address_street_word_id]
1621            AND rank_search < NEW.rank_search
1622            AND (NEW.country_code IS NULL OR search_name.country_code = NEW.country_code OR search_name.address_rank < 4)
1623            ORDER BY ST_distance(NEW.geometry, search_name.centroid) ASC limit 1
1624          LOOP
1625
1626            IF NEW.country_code IS NULL THEN
1627              NEW.country_code := location.country_code;
1628            ELSEIF NEW.country_code != location.country_code and location.rank_search > 3 THEN
1629              search_country_code_conflict := true;
1630            END IF;
1631
1632--RAISE WARNING '  found: %',location.place_id;
1633            nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1634            INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1635
1636            IF address_maxrank > location.rank_address THEN
1637              address_maxrank := location.rank_address;
1638            END IF;
1639          END LOOP;
1640        END IF;
1641      END LOOP;
1642      FOR i IN address_maxrank..28 LOOP
1643        address_havelevel[i] := true;
1644      END LOOP;
1645    END IF;
1646
1647    -- If we have got a consistent country code from the areas and/or isin then we don't care about points (too inacurate)
1648    bPointCountryCode := NEW.country_code IS NULL;
1649
1650    IF true THEN
1651    -- full search using absolute position
1652
1653    search_diameter := 0;
1654    -- 16 = city, anything larger tends to be an area so don't continue
1655    WHILE search_diameter < 1 AND search_maxrank > 16 LOOP
1656
1657--      RAISE WARNING 'Nearest: % %', search_diameter, search_maxrank;
1658
1659      search_prevdiameter := search_diameter;
1660      IF search_diameter = 0 THEN
1661        search_diameter := 0.001;
1662      ELSE
1663        search_diameter := search_diameter * 2;
1664      END IF;
1665
1666--RAISE WARNING '%', 'SELECT place_id, name, keywords, country_code, rank_address, rank_search,'||
1667--        'ST_Distance('||place_geometry_text||', centroid) as distance,'||
1668--        'ST_Distance('||place_geometry_text||', centroid) as maxdistance'|| -- this version of postgis doesnt have maxdistance !
1669--        ' FROM location_point_'||(case when search_maxrank > 26 THEN 26 ELSE search_maxrank end)||
1670--        ' WHERE ST_DWithin('||place_geometry_text||', centroid, '||search_diameter||') '||
1671--        '  AND ST_Distance('||place_geometry_text||', centroid) > '||search_prevdiameter||
1672--        ' ORDER BY ST_Distance('||place_geometry_text||', centroid) ASC';
1673
1674      -- Try nearest
1675      FOR location IN EXECUTE 'SELECT place_id, name, keywords, country_code, rank_address, rank_search,'||
1676        'ST_Distance('||place_geometry_text||', centroid) as distance,'||
1677        'ST_Distance('||place_geometry_text||', centroid) as maxdistance'|| -- this version of postgis doesnt have maxdistance !
1678        ' FROM location_point_'||(case when search_maxrank > 26 THEN 26 ELSE search_maxrank end)||
1679        ' WHERE ST_DWithin('||place_geometry_text||', centroid, '||search_diameter||') '||
1680        '  AND ST_Distance('||place_geometry_text||', centroid) >= '||search_prevdiameter||
1681        ' ORDER BY ST_Distance('||place_geometry_text||', centroid) ASC'
1682      LOOP
1683
1684        IF bPointCountryCode THEN     
1685          IF NEW.country_code IS NULL THEN
1686            NEW.country_code := location.country_code;
1687          ELSEIF NEW.country_code != location.country_code THEN
1688            search_country_code_conflict := true;
1689          END IF;
1690        END IF;
1691   
1692        -- Find search words
1693--RAISE WARNING 'IF % % % %', location.name, location.distance, location.rank_search, search_maxdistance;
1694--RAISE WARNING '  POINT: % % % % %', location.name, location.rank_search, location.place_id, location.distance, search_maxdistance[location.rank_search];
1695        IF (location.distance < search_maxdistance[location.rank_search]) THEN
1696--RAISE WARNING '  adding';     
1697          -- Add it to the list of search terms, de-duplicate
1698          nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1699   
1700          iMax := (location.maxdistance*1.5)::float;
1701          FOR i IN location.rank_search..28 LOOP
1702            IF iMax < search_maxdistance[i] THEN
1703--RAISE WARNING '  setting % to %',i,iMax;     
1704              IF iMax > search_mindistance[i] THEN
1705                search_maxdistance[i] := iMax;
1706              ELSE
1707                search_maxdistance[i] := search_mindistance[i];
1708              END IF;
1709            END IF;
1710          END LOOP;
1711
1712          INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1713          address_havelevel[location.rank_address] := true;
1714 
1715        ELSE
1716--RAISE WARNING '  Stopped: % % % %', location.rank_search, location.distance, search_maxdistance[location.rank_search], location.name;
1717          IF search_maxrank > location.rank_search THEN
1718            search_maxrank := location.rank_search;
1719          END IF;
1720        END IF;
1721   
1722      END LOOP;
1723 
1724--RAISE WARNING '  POINT LOCATIONS, % %', search_maxrank, search_diameter;
1725 
1726    END LOOP; --WHILE
1727
1728    ELSE
1729      -- Cascading search using nearest parent
1730    END IF;
1731
1732    IF search_country_code_conflict OR NEW.country_code IS NULL THEN
1733      NEW.country_code := get_country_code(place_centroid);
1734    END IF;
1735
1736    INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, NEW.country_code,
1737      name_vector, nameaddress_vector, place_centroid);
1738
1739    IF NEW.country_code IS NOT NULL THEN
1740      DELETE FROM place_addressline WHERE place_id = NEW.place_id and address_place_id in (
1741        select address_place_id from place_addressline join placex on (address_place_id = placex.place_id)
1742          where place_addressline.place_id = NEW.place_id and placex.country_code != NEW.country_code and cached_rank_address >= 4);
1743    END IF;
1744
1745  END IF;
1746
1747  return NEW;
1748END;
1749$$
1750LANGUAGE plpgsql;
1751
1752CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1753  AS $$
1754DECLARE
1755BEGIN
1756
1757--IF OLD.rank_search < 26 THEN
1758--RAISE WARNING 'delete % % % % %',OLD.place_id,OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1759--END IF;
1760
1761  -- mark everything linked to this place for re-indexing
1762  UPDATE placex set indexed = false from place_addressline where address_place_id = OLD.place_id and placex.place_id = place_addressline.place_id and indexed;
1763
1764  -- do the actual delete
1765  DELETE FROM location_area where place_id = OLD.place_id;
1766  DELETE FROM location_point where place_id = OLD.place_id;
1767  DELETE FROM location_point_0 where place_id = OLD.place_id;
1768  DELETE FROM location_point_1 where place_id = OLD.place_id;
1769  DELETE FROM location_point_2 where place_id = OLD.place_id;
1770  DELETE FROM location_point_3 where place_id = OLD.place_id;
1771  DELETE FROM location_point_4 where place_id = OLD.place_id;
1772  DELETE FROM location_point_5 where place_id = OLD.place_id;
1773  DELETE FROM location_point_6 where place_id = OLD.place_id;
1774  DELETE FROM location_point_7 where place_id = OLD.place_id;
1775  DELETE FROM location_point_8 where place_id = OLD.place_id;
1776  DELETE FROM location_point_9 where place_id = OLD.place_id;
1777  DELETE FROM location_point_10 where place_id = OLD.place_id;
1778  DELETE FROM location_point_11 where place_id = OLD.place_id;
1779  DELETE FROM location_point_12 where place_id = OLD.place_id;
1780  DELETE FROM location_point_13 where place_id = OLD.place_id;
1781  DELETE FROM location_point_14 where place_id = OLD.place_id;
1782  DELETE FROM location_point_15 where place_id = OLD.place_id;
1783  DELETE FROM location_point_16 where place_id = OLD.place_id;
1784  DELETE FROM location_point_17 where place_id = OLD.place_id;
1785  DELETE FROM location_point_18 where place_id = OLD.place_id;
1786  DELETE FROM location_point_19 where place_id = OLD.place_id;
1787  DELETE FROM location_point_20 where place_id = OLD.place_id;
1788  DELETE FROM location_point_21 where place_id = OLD.place_id;
1789  DELETE FROM location_point_22 where place_id = OLD.place_id;
1790  DELETE FROM location_point_23 where place_id = OLD.place_id;
1791  DELETE FROM location_point_24 where place_id = OLD.place_id;
1792  DELETE FROM location_point_25 where place_id = OLD.place_id;
1793  DELETE FROM location_point_26 where place_id = OLD.place_id;
1794  DELETE FROM search_name where place_id = OLD.place_id;
1795  DELETE FROM place_addressline where place_id = OLD.place_id;
1796  DELETE FROM place_addressline where address_place_id = OLD.place_id;
1797
1798  RETURN OLD;
1799
1800END;
1801$$
1802LANGUAGE plpgsql;
1803
1804CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1805  AS $$
1806DECLARE
1807  placeid INTEGER;
1808BEGIN
1809
1810--  RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1811  delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1812  RETURN OLD;
1813
1814END;
1815$$
1816LANGUAGE plpgsql;
1817
1818CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1819  AS $$
1820DECLARE
1821  i INTEGER;
1822  existing RECORD;
1823  existingplacex RECORD;
1824  existinggeometry GEOMETRY;
1825  existingplace_id bigint;
1826  result BOOLEAN;
1827BEGIN
1828
1829  IF FALSE AND NEW.osm_type = 'R' THEN
1830    RAISE WARNING '-----------------------------------------------------------------------------------';
1831    RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1832    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;
1833    RAISE WARNING '%', existingplacex;
1834  END IF;
1835
1836  -- Just block these - lots and pointless
1837  IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1838    RETURN null;
1839  END IF;
1840  IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1841    RETURN null;
1842  END IF;
1843
1844  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 
1845--    RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1846    RETURN null;
1847  END IF;
1848
1849  -- Patch in additional country names
1850  -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2
1851  IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN
1852    select add_keywords(NEW.name, country_name.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1853  END IF;
1854   
1855  -- Have we already done this place?
1856  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;
1857
1858  -- Get the existing place_id
1859  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;
1860
1861  -- Handle a place changing type by removing the old data
1862  -- My generated 'place' types are causing havok because they overlap with real tags
1863  -- TODO: move them to their own special purpose tag to avoid collisions
1864  IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1865    DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses');
1866  END IF;
1867
1868--  RAISE WARNING 'Existing: %',existing.place_id;
1869
1870  -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry
1871  IF existing.osm_type IS NULL
1872     OR existingplacex.osm_type IS NULL
1873     OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1874--     OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1875     OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1876     (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1877     THEN
1878
1879--  IF existing.osm_type IS NULL THEN
1880--    RAISE WARNING 'no existing place';
1881--  END IF;
1882--  IF existingplacex.osm_type IS NULL THEN
1883--    RAISE WARNING 'no existing placex %', existingplacex;
1884--  END IF;
1885
1886
1887--    RAISE WARNING 'delete and replace';
1888
1889    IF existing.osm_type IS NOT NULL THEN
1890--      RAISE WARNING 'insert delete % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)),existing;
1891      IF existing.rank_search < 26 THEN
1892--        RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1893      END IF;
1894      DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1895    END IF;   
1896
1897--    RAISE WARNING 'delete and replace2';
1898
1899    -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1900    insert into placex values (NEW.place_id
1901        ,NEW.osm_type
1902        ,NEW.osm_id
1903        ,NEW.class
1904        ,NEW.type
1905        ,NEW.name
1906        ,NEW.admin_level
1907        ,NEW.housenumber
1908        ,NEW.street
1909        ,NEW.isin
1910        ,NEW.postcode
1911        ,NEW.country_code
1912        ,NEW.street_place_id
1913        ,NEW.rank_address
1914        ,NEW.rank_search
1915        ,NEW.indexed
1916        ,NEW.geometry
1917        );
1918
1919--    RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1920
1921    RETURN NEW;
1922  END IF;
1923
1924  -- Various ways to do the update
1925
1926  -- Debug, what's changed?
1927  IF FALSE AND existing.rank_search < 26 THEN
1928    IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1929      RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1930    END IF;
1931    IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1932      RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1933    END IF;
1934    IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1935      RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1936    END IF;
1937    IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1938      RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1939    END IF;
1940    IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1941      RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1942    END IF;
1943    IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1944      RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1945    END IF;
1946  END IF;
1947
1948  -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1949  IF existing.geometry != NEW.geometry
1950     AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1951     AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1952     THEN
1953
1954--    IF existing.rank_search < 26 THEN
1955--      RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1956--    END IF;
1957
1958    -- Get the version of the geometry actually used (in placex table)
1959    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;
1960
1961    -- Performance limit
1962    IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN
1963
1964      -- 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
1965      update placex set indexed = false where indexed and
1966          (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1967          AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1968          AND rank_search > NEW.rank_search;
1969
1970      update placex set indexed = false where indexed and
1971          (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1972          AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1973          AND rank_search > NEW.rank_search;
1974
1975    END IF;
1976
1977  END IF;
1978
1979  -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1980  IF existingplacex.rank_search < 26
1981     AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1982     AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1983     AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1984     AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1985     AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1986     AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1987     THEN
1988
1989--    IF existing.rank_search < 26 THEN
1990--      RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1991--    END IF;
1992
1993    IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1994
1995      IF st_area(NEW.geometry) < 0.5 THEN
1996        UPDATE placex set indexed = false from place_addressline where address_place_id = existingplacex.place_id
1997          and placex.place_id = place_addressline.place_id and indexed;
1998      END IF;
1999
2000    END IF;
2001 
2002  ELSE
2003
2004    -- Anything else has changed - reindex the lot
2005    IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2006        OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2007        OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2008        OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2009        OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2010        OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2011
2012--      IF existing.rank_search < 26 THEN
2013--        RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2014--      END IF;
2015
2016      -- performance, can't take the load of re-indexing a whole country / huge area
2017      IF st_area(NEW.geometry) < 0.5 THEN
2018        UPDATE placex set indexed = false from place_addressline where address_place_id = existingplacex.place_id
2019          and placex.place_id = place_addressline.place_id and indexed;
2020      END IF;
2021
2022    END IF;
2023
2024  END IF;
2025
2026  IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2027     OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2028     OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2029     OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2030     OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2031     OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2032     OR existing.geometry != NEW.geometry
2033     THEN
2034
2035    update place set
2036      name = NEW.name,
2037      housenumber  = NEW.housenumber,
2038      street = NEW.street,
2039      isin = NEW.isin,
2040      postcode = NEW.postcode,
2041      country_code = NEW.country_code,
2042      street_place_id = null,
2043      geometry = NEW.geometry
2044      where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2045
2046    update placex set
2047      name = NEW.name,
2048      housenumber = NEW.housenumber,
2049      street = NEW.street,
2050      isin = NEW.isin,
2051      postcode = NEW.postcode,
2052      country_code = NEW.country_code,
2053      street_place_id = null,
2054      indexed = false,
2055      geometry = NEW.geometry
2056      where place_id = existingplacex.place_id;
2057
2058    result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
2059
2060  END IF;
2061
2062  -- Abort the add (we modified the existing place instead)
2063  RETURN NULL;
2064
2065END;
2066$$ LANGUAGE plpgsql;
2067
2068CREATE OR REPLACE FUNCTION get_name_by_language(name keyvalue[], languagepref TEXT[]) RETURNS TEXT
2069  AS $$
2070DECLARE
2071  search TEXT[];
2072  found BOOLEAN;
2073BEGIN
2074
2075  IF (array_upper(name, 1) is null) THEN
2076    return null;
2077  END IF;
2078
2079  search := languagepref;
2080
2081  FOR j IN 1..array_upper(search, 1) LOOP
2082    FOR k IN 1..array_upper(name, 1) LOOP
2083      IF (name[k].key = search[j] AND trim(name[k].value) != '') THEN
2084        return trim(name[k].value);
2085      END IF;
2086    END LOOP;
2087  END LOOP;
2088
2089  RETURN null;
2090END;
2091$$
2092LANGUAGE plpgsql IMMUTABLE;
2093
2094CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2095  AS $$
2096DECLARE
2097  searchnodes INTEGER[];
2098  location RECORD;
2099  j INTEGER;
2100BEGIN
2101
2102  searchnodes := '{}';
2103  FOR j IN 1..array_upper(way_ids, 1) LOOP
2104    FOR location IN
2105      select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2106    LOOP
2107      searchnodes := searchnodes | location.nodes;
2108    END LOOP;
2109  END LOOP;
2110
2111  RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2112END;
2113$$
2114LANGUAGE plpgsql IMMUTABLE;
2115
2116CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2117  AS $$
2118DECLARE
2119  result TEXT[];
2120  search TEXT[];
2121  for_postcode TEXT;
2122  found INTEGER;
2123  location RECORD;
2124BEGIN
2125
2126  found := 1000;
2127  search := ARRAY['ref'];
2128  result := '{}';
2129
2130  UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
2131
2132  select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2133
2134  FOR location IN
2135    select rank_address,name,distance,length(name::text) as namelength
2136      from place_addressline join placex on (address_place_id = placex.place_id)
2137      where place_addressline.place_id = for_place_id and rank_address in (5,11)
2138      order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2139  LOOP
2140    IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2141      FOR j IN 1..array_upper(search, 1) LOOP
2142        FOR k IN 1..array_upper(location.name, 1) LOOP
2143          IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result && ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN
2144            result[(100 - location.rank_address)] := trim(location.name[k].value);
2145            found := location.rank_address;
2146          END IF;
2147        END LOOP;
2148      END LOOP;
2149    END IF;
2150  END LOOP;
2151
2152  RETURN array_to_string(result,', ');
2153END;
2154$$
2155LANGUAGE plpgsql;
2156
2157CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2158  AS $$
2159DECLARE
2160  result TEXT[];
2161  search TEXT[];
2162  found INTEGER;
2163  location RECORD;
2164  searchcountrycode varchar(2);
2165  searchhousenumber TEXT;
2166  searchrankaddress INTEGER;
2167BEGIN
2168
2169  found := 1000;
2170  search := languagepref;
2171  result := '{}';
2172
2173--  UPDATE placex set indexed = false where indexed = true and place_id = for_place_id;
2174  UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
2175
2176  select country_code,housenumber,rank_address from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress;
2177
2178  FOR location IN
2179    select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
2180      CASE WHEN type = 'postcode' THEN ARRAY[ROW('name',postcode)::keyvalue] ELSE name END as name,
2181      distance,length(name::text) as namelength
2182      from place_addressline join placex on (address_place_id = placex.place_id)
2183      where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id)
2184      and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2185      order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
2186  LOOP
2187    IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2188      FOR j IN 1..array_upper(search, 1) LOOP
2189        FOR k IN 1..array_upper(location.name, 1) LOOP
2190          IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result && ARRAY[trim(location.name[k].value)] THEN
2191            result[(100 - location.rank_address)] := trim(location.name[k].value);
2192            found := location.rank_address;
2193          END IF;
2194        END LOOP;
2195      END LOOP;
2196    END IF;
2197  END LOOP;
2198
2199  IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN
2200    IF result[(100 - 28)] IS NOT NULL THEN
2201      result[(100 - 29)] := result[(100 - 28)];
2202    END IF;
2203    result[(100 - 28)] := searchhousenumber;
2204  END IF;
2205
2206  -- No country polygon - add it from the country_code
2207  IF found > 4 THEN
2208    select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
2209      where place_id = for_place_id limit 1 INTO location;
2210    IF location IS NOT NULL THEN
2211      result[(100 - 4)] := trim(location.name);
2212    END IF;
2213  END IF;
2214
2215  RETURN array_to_string(result,', ');
2216END;
2217$$
2218LANGUAGE plpgsql;
2219
2220CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT[]
2221  AS $$
2222DECLARE
2223  result TEXT[];
2224  search TEXT[];
2225  found INTEGER;
2226  location RECORD;
2227  searchcountrycode varchar(2);
2228  searchhousenumber TEXT;
2229BEGIN
2230
2231  found := 1000;
2232  search := languagepref;
2233  result := '{}';
2234
2235--  UPDATE placex set indexed = false where indexed = true and place_id = for_place_id;
2236  UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
2237
2238  select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber;
2239
2240  FOR location IN
2241    select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
2242      name,distance,length(name::text) as namelength
2243      from place_addressline join placex on (address_place_id = placex.place_id)
2244      where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id)
2245      and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2246      order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
2247  LOOP
2248    IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2249      FOR j IN 1..array_upper(search, 1) LOOP
2250        FOR k IN 1..array_upper(location.name, 1) LOOP
2251          IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result && ARRAY[trim(location.name[k].value)] THEN
2252            result[(100 - location.rank_address)] := trim(location.name[k].value);
2253            found := location.rank_address;
2254          END IF;
2255        END LOOP;
2256      END LOOP;
2257    END IF;
2258  END LOOP;
2259
2260  IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN
2261    result[(100 - 28)] := searchhousenumber;
2262  END IF;
2263
2264  -- No country polygon - add it from the country_code
2265  IF found > 4 THEN
2266    select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
2267      where place_id = for_place_id limit 1 INTO location;
2268    IF location IS NOT NULL THEN
2269      result[(100 - 4)] := trim(location.name);
2270    END IF;
2271  END IF;
2272
2273  RETURN result;
2274END;
2275$$
2276LANGUAGE plpgsql;
2277
2278CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
2279  AS $$
2280DECLARE
2281  result place_boundingbox;
2282  numfeatures integer;
2283BEGIN
2284  select * from place_boundingbox into result where place_id = search_place_id;
2285  IF result.place_id IS NULL THEN
2286-- remove  isaddress = true because if there is a matching polygon it always wins
2287    select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2288    insert into place_boundingbox select place_id,
2289             ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),2)),
2290             ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),3)),
2291             numfeatures, ST_Area(area),
2292             area from location_area where place_id = search_place_id;
2293    select * from place_boundingbox into result where place_id = search_place_id;
2294  END IF;
2295  IF result.place_id IS NULL THEN
2296-- TODO 0.0001
2297    insert into place_boundingbox select address_place_id,
2298             min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2299             min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2300             count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2301             ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2302             from (select * from place_addressline where address_place_id = search_place_id order by cached_rank_address limit 4000) as place_addressline join placex using (place_id)
2303             where address_place_id = search_place_id
2304--               and (isaddress = true OR place_id = search_place_id)
2305               and (st_length(geometry) < 0.01 or place_id = search_place_id)
2306             group by address_place_id limit 1;
2307    select * from place_boundingbox into result where place_id = search_place_id;
2308  END IF;
2309  return result;
2310END;
2311$$
2312LANGUAGE plpgsql;
2313
2314-- don't do the operation if it would be slow
2315CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
2316  AS $$
2317DECLARE
2318  result place_boundingbox;
2319  numfeatures integer;
2320  rank integer;
2321BEGIN
2322  select * from place_boundingbox into result where place_id = search_place_id;
2323  IF result IS NULL AND rank > 14 THEN
2324    select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2325    insert into place_boundingbox select place_id,
2326             ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),2)),
2327             ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),3)),
2328             numfeatures, ST_Area(area),
2329             area from location_area where place_id = search_place_id;
2330    select * from place_boundingbox into result where place_id = search_place_id;
2331  END IF;
2332  IF result IS NULL THEN
2333    select rank_search from placex where place_id = search_place_id into rank;
2334    IF rank > 20 THEN
2335-- TODO 0.0001
2336      insert into place_boundingbox select address_place_id,
2337             min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2338             min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2339             count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2340             ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2341             from place_addressline join placex using (place_id)
2342             where address_place_id = search_place_id
2343               and (isaddress = true OR place_id = search_place_id)
2344               and (st_length(geometry) < 0.01 or place_id = search_place_id)
2345             group by address_place_id limit 1;
2346      select * from place_boundingbox into result where place_id = search_place_id;
2347    END IF;
2348  END IF;
2349  return result;
2350END;
2351$$
2352LANGUAGE plpgsql;
2353
2354CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2355  AS $$
2356DECLARE
2357  result place_boundingbox;
2358  numfeatures integer;
2359BEGIN
2360  update placex set
2361      name = place.name,
2362      housenumber = place.housenumber,
2363      street = place.street,
2364      isin = place.isin,
2365      postcode = place.postcode,
2366      country_code = place.country_code,
2367      street_place_id = null,
2368      indexed = false     
2369      from place
2370      where placex.place_id = search_place_id
2371        and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2372        and place.class = placex.class and place.type = placex.type;
2373  update placex set indexed = true where place_id = search_place_id and indexed = false;
2374  return true;
2375END;
2376$$
2377LANGUAGE plpgsql;
2378
2379CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2380  AS $$
2381DECLARE
2382  result place_boundingbox;
2383  numfeatures integer;
2384BEGIN
2385  update placex set
2386      name = place.name,
2387      housenumber = place.housenumber,
2388      street = place.street,
2389      isin = place.isin,
2390      postcode = place.postcode,
2391      country_code = place.country_code,
2392      street_place_id = null,
2393      indexed = false     
2394      from place
2395      where placex.place_id = search_place_id
2396        and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2397        and place.class = placex.class and place.type = placex.type;
2398  update placex set indexed = true where place_id = search_place_id and indexed = false;
2399  return true;
2400END;
2401$$
2402LANGUAGE plpgsql;
2403
2404CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2405  AS $$
2406DECLARE
2407BEGIN
2408  IF rank < 2 THEN
2409    RETURN 'Continent';
2410  ELSEIF rank < 4 THEN
2411    RETURN 'Sea';
2412  ELSEIF rank < 8 THEN
2413    RETURN 'Country';
2414  ELSEIF rank < 12 THEN
2415    RETURN 'State';
2416  ELSEIF rank < 16 THEN
2417    RETURN 'County';
2418  ELSEIF rank = 16 THEN
2419    RETURN 'City';
2420  ELSEIF rank = 17 THEN
2421    RETURN 'Town / Island';
2422  ELSEIF rank = 18 THEN
2423    RETURN 'Village / Hamlet';
2424  ELSEIF rank = 20 THEN
2425    RETURN 'Suburb';
2426  ELSEIF rank = 21 THEN
2427    RETURN 'Postcode Area';
2428  ELSEIF rank = 22 THEN
2429    RETURN 'Croft / Farm / Locality / Islet';
2430  ELSEIF rank = 23 THEN
2431    RETURN 'Postcode Area';
2432  ELSEIF rank = 25 THEN
2433    RETURN 'Postcode Point';
2434  ELSEIF rank = 26 THEN
2435    RETURN 'Street / Major Landmark';
2436  ELSEIF rank = 27 THEN
2437    RETURN 'Minory Street / Path';
2438  ELSEIF rank = 28 THEN
2439    RETURN 'House / Building';
2440  ELSE
2441    RETURN 'Other: '||rank;
2442  END IF;
2443 
2444END;
2445$$
2446LANGUAGE plpgsql;
2447
2448CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2449  AS $$
2450DECLARE
2451BEGIN
2452  IF rank = 0 THEN
2453    RETURN 'None';
2454  ELSEIF rank < 2 THEN
2455    RETURN 'Continent';
2456  ELSEIF rank < 4 THEN
2457    RETURN 'Sea';
2458  ELSEIF rank = 5 THEN
2459    RETURN 'Postcode';
2460  ELSEIF rank < 8 THEN
2461    RETURN 'Country';
2462  ELSEIF rank < 12 THEN
2463    RETURN 'State';
2464  ELSEIF rank < 16 THEN
2465    RETURN 'County';
2466  ELSEIF rank = 16 THEN
2467    RETURN 'City';
2468  ELSEIF rank = 17 THEN
2469    RETURN 'Town / Village / Hamlet';
2470  ELSEIF rank = 20 THEN
2471    RETURN 'Suburb';
2472  ELSEIF rank = 21 THEN
2473    RETURN 'Postcode Area';
2474  ELSEIF rank = 22 THEN
2475    RETURN 'Croft / Farm / Locality / Islet';
2476  ELSEIF rank = 23 THEN
2477    RETURN 'Postcode Area';
2478  ELSEIF rank = 25 THEN
2479    RETURN 'Postcode Point';
2480  ELSEIF rank = 26 THEN
2481    RETURN 'Street / Major Landmark';
2482  ELSEIF rank = 27 THEN
2483    RETURN 'Minory Street / Path';
2484  ELSEIF rank = 28 THEN
2485    RETURN 'House / Building';
2486  ELSE
2487    RETURN 'Other: '||rank;
2488  END IF;
2489 
2490END;
2491$$
2492LANGUAGE plpgsql;
2493
2494CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2495  AS $$
2496DECLARE
2497  trigramtoken TEXT;
2498  result TEXT;
2499BEGIN
2500
2501  trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2502  SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2503
2504  return result;
2505END;
2506$$
2507LANGUAGE plpgsql;
2508
2509CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2510  AS $$
2511DECLARE
2512  trigramtoken TEXT;
2513  result TEXT[];
2514  r RECORD;
2515BEGIN
2516
2517  trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2518
2519  FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2520    WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2521  LOOP
2522    result[coalesce(array_upper(result,1)+1,1)] := r.word;
2523  END LOOP;
2524
2525  return result;
2526END;
2527$$
2528LANGUAGE plpgsql;
2529
2530
2531CREATE OR REPLACE FUNCTION get_word_letterfequency(srcword TEXT) RETURNS INTEGER[]
2532  AS $$
2533DECLARE
2534  letterfeq INTEGER[];
2535  i INTEGER;
2536BEGIN
2537  letterfeq[97] := 0;
2538  letterfeq[101] := 0;
2539  letterfeq[105] := 0;
2540  letterfeq[114] := 0;
2541  letterfeq[116] := 0;
2542  letterfeq[115] := 0;
2543  letterfeq[111] := 0;
2544  letterfeq[117] := 0;
2545  letterfeq[110] := 0;
2546  letterfeq[100] := 0;
2547  FOR i IN 1..length(srcword) LOOP
2548    i := ascii(substring(srcword, i, 1));
2549    IF (i = 97 OR i = 101 OR i = 105 OR i = 114 OR i = 116 OR i = 115 OR i = 111 OR i = 117 OR i = 110 OR i = 100) AND letterfeq[i] < 7 THEN
2550      letterfeq[i] := letterfeq[i] + 1;
2551    END IF;
2552  END LOOP;
2553  RETURN letterfeq;
2554END;
2555$$
2556LANGUAGE plpgsql;
2557
2558CREATE OR REPLACE FUNCTION get_word_indexval(a INTEGER,e INTEGER,i INTEGER,r INTEGER,t INTEGER,s INTEGER,o INTEGER,u INTEGER,n INTEGER,d INTEGER) RETURNS INTEGER
2559  AS $$
2560DECLARE
2561BEGIN
2562  RETURN (a << 0) + (e << 3) + (i << 6) + (r << 9) + (t << 12) + (s << 15) + (o << 18) + (u << 21) + (n << 24) + (d << 27);
2563END;
2564$$
2565LANGUAGE plpgsql;
2566
2567CREATE OR REPLACE FUNCTION get_word_indexkey(srcword TEXT) RETURNS INTEGER
2568  AS $$
2569DECLARE
2570  letterfeq INTEGER[];
2571BEGIN
2572
2573  letterfeq := get_word_letterfequency(srcword);
2574  RETURN get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2575
2576END;
2577$$
2578LANGUAGE plpgsql;
2579
2580CREATE OR REPLACE FUNCTION get_word_indexnear(srcword TEXT) RETURNS INTEGER[]
2581  AS $$
2582DECLARE
2583  letterfeq INTEGER[];
2584  near INTEGER[];
2585BEGIN
2586
2587
2588  letterfeq := get_word_letterfequency(srcword);
2589
2590  near := ARRAY[get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100])];
2591
2592  IF letterfeq[97] > 0 THEN
2593    near := near || get_word_indexval(letterfeq[97]-1, letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2594  END IF;
2595  IF letterfeq[97] < 7 THEN
2596    near := near || get_word_indexval(letterfeq[97]+1, letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2597  END IF;
2598
2599  IF letterfeq[101] > 0 THEN
2600    near := near || get_word_indexval(letterfeq[97], letterfeq[101]-1, letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2601  END IF;
2602  IF letterfeq[101] < 7 THEN
2603    near := near || get_word_indexval(letterfeq[97], letterfeq[101]+1, letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2604  END IF;
2605
2606  IF letterfeq[105] > 0 THEN
2607    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105]-1, letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2608  END IF;
2609  IF letterfeq[105] < 7 THEN
2610    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105]+1, letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2611  END IF;
2612
2613  IF letterfeq[114] > 0 THEN
2614    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114]-1, letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2615  END IF;
2616  IF letterfeq[114] < 7 THEN
2617    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114]+1, letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2618  END IF;
2619
2620  IF letterfeq[116] > 0 THEN
2621    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116]-1, letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2622  END IF;
2623  IF letterfeq[116] < 7 THEN
2624    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116]+1, letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2625  END IF;
2626
2627  IF letterfeq[115] > 0 THEN
2628    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115]-1, letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2629  END IF;
2630  IF letterfeq[115] < 7 THEN
2631    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115]+1, letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]);
2632  END IF;
2633
2634  IF letterfeq[111] > 0 THEN
2635    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111]-1, letterfeq[117], letterfeq[110], letterfeq[100]);
2636  END IF;
2637  IF letterfeq[111] < 7 THEN
2638    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111]+1, letterfeq[117], letterfeq[110], letterfeq[100]);
2639  END IF;
2640
2641  IF letterfeq[117] > 0 THEN
2642    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117]-1, letterfeq[110], letterfeq[100]);
2643  END IF;
2644  IF letterfeq[117] < 7 THEN
2645    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117]+1, letterfeq[110], letterfeq[100]);
2646  END IF;
2647
2648  IF letterfeq[110] > 0 THEN
2649    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110]-1, letterfeq[100]);
2650  END IF;
2651  IF letterfeq[110] < 7 THEN
2652    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110]+1, letterfeq[100]);
2653  END IF;
2654
2655  IF letterfeq[100] > 0 THEN
2656    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]-1);
2657  END IF;
2658  IF letterfeq[100] < 7 THEN
2659    near := near || get_word_indexval(letterfeq[97], letterfeq[101], letterfeq[105], letterfeq[114], letterfeq[116], letterfeq[115], letterfeq[111], letterfeq[117], letterfeq[110], letterfeq[100]+1);
2660  END IF;
2661
2662  RETURN near; 
2663END;
2664$$
2665LANGUAGE plpgsql;
2666
2667CREATE OR REPLACE FUNCTION get_trigram_ids(lookup_word TEXT)
2668  RETURNS INTEGER[]
2669  AS $$
2670DECLARE
2671  gram1 INTEGER;
2672  gram2 INTEGER;
2673  gram3 INTEGER;
2674
2675  gram INTEGER[];
2676  gramsorted INTEGER[];
2677  trigramgram INTEGER[];
2678BEGIN
2679
2680  trigramgram := '{}'::int[];
2681  gram := '{1,1,1}'::int[];
2682
2683  FOR i in 1..length(lookup_word) LOOP
2684    gram[1] := gram[2];
2685    gram[2] := gram[3];
2686    gram[3] := ascii(substring(lookup_word,i,1));
2687    gramsorted := sort(gram);
2688    trigramgram := trigramgram + (gramsorted[1] + gramsorted[2]*128 + gramsorted[3]*16384);
2689  END LOOP;
2690
2691  gram[1] := gram[2];
2692  gram[2] := gram[3];
2693  gram[3] := 1;
2694  gramsorted := sort(gram);
2695  trigramgram := trigramgram + (gramsorted[1] + gramsorted[2]*128 + gramsorted[3]*16384);
2696
2697  gram[1] := gram[2];
2698  gram[2] := gram[3];
2699  gram[3] := 1;
2700  gramsorted := sort(gram);
2701  trigramgram := trigramgram + (gramsorted[1] + gramsorted[2]*128 + gramsorted[3]*16384);
2702
2703  RETURN uniq(sort(trigramgram));
2704END;
2705$$
2706LANGUAGE plpgsql;
2707
Note: See TracBrowser for help on using the repository browser.