remove unused columns from word and search_name_* tables

Removes 'trigram' and 'location' from word.
  Removes 'address', 'importance' and 'country_code' from search_name_*.
  Use full geometry in centroid column of search_name_*.

  Requires migration of existing tables. For more info see pull request
  https://github.com/twain47/Nominatim/pull/45
This commit is contained in:
Sarah Hoffmann
2013-04-09 22:44:05 +02:00
parent 4d2b88dd3e
commit 23d303124e
6 changed files with 34 additions and 32 deletions

View File

@@ -95,7 +95,7 @@ BEGIN
SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
ELSE
IF count > get_maxwordfreq() THEN
return_word_id := NULL;
@@ -117,7 +117,7 @@ BEGIN
SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
END IF;
RETURN return_word_id;
END;
@@ -135,7 +135,7 @@ BEGIN
SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
END IF;
RETURN return_word_id;
END;
@@ -153,7 +153,7 @@ BEGIN
SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
END IF;
RETURN return_word_id;
END;
@@ -171,7 +171,7 @@ BEGIN
SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
END IF;
RETURN return_word_id;
END;
@@ -203,7 +203,7 @@ BEGIN
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;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
END IF;
RETURN return_word_id;
END;
@@ -222,7 +222,7 @@ BEGIN
SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
-- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
-- IF ' '||nospace_lookup_token != lookup_token THEN
-- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
@@ -1560,7 +1560,7 @@ BEGIN
result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
END IF;
result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
return NEW;
END IF;
@@ -1891,9 +1891,8 @@ BEGIN
result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
END IF;
result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
-- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.calculated_country_code, name_vector, nameaddress_vector, place_centroid);
END IF;
-- If we've not managed to pick up a better one - default centroid
@@ -2344,7 +2343,7 @@ END;
$$
LANGUAGE plpgsql;
DROP TYPE addressline CASCADE;
DROP TYPE IF EXISTS addressline CASCADE;
create type addressline as (
place_id BIGINT,
osm_type CHAR(1),

View File

@@ -21,7 +21,6 @@ CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) wh
CREATE INDEX idx_location_area_country_place_id ON location_area_country USING BTREE (place_id);
CREATE INDEX idx_search_name_country_centroid ON search_name_country USING GIST (centroid);
CREATE INDEX idx_search_name_country_nameaddress_vector ON search_name_country USING GIN (nameaddress_vector) WITH (fastupdate = off);
-- start
CREATE INDEX idx_location_property_-partition-_centroid ON location_property_-partition- USING GIST (centroid);

View File

@@ -166,7 +166,7 @@ create or replace function insertSearchName(
in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2),
in_name_vector INTEGER[], in_nameaddress_vector INTEGER[],
in_rank_search INTEGER, in_rank_address INTEGER, in_importance FLOAT,
in_centroid GEOMETRY) RETURNS BOOLEAN AS $$
in_centroid GEOMETRY, in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
DECLARE
BEGIN
@@ -176,16 +176,16 @@ BEGIN
IF in_rank_search <= 4 THEN
DELETE FROM search_name_country WHERE place_id = in_place_id;
INSERT INTO search_name_country values (in_place_id, in_rank_search, in_rank_address, in_importance, in_country_code,
in_name_vector, in_nameaddress_vector, in_centroid);
INSERT INTO search_name_country values (in_place_id, in_rank_search, in_rank_address,
in_name_vector, in_geometry);
RETURN TRUE;
END IF;
-- start
IF in_partition = -partition- THEN
DELETE FROM search_name_-partition- values WHERE place_id = in_place_id;
INSERT INTO search_name_-partition- values (in_place_id, in_rank_search, in_rank_address, 0, in_country_code,
in_name_vector, in_nameaddress_vector, in_centroid);
INSERT INTO search_name_-partition- values (in_place_id, in_rank_search, in_rank_address,
in_name_vector, in_geometry);
RETURN TRUE;
END IF;
-- end

View File

@@ -1,9 +1,9 @@
drop type nearplace cascade;
drop type if exists nearplace cascade;
create type nearplace as (
place_id BIGINT
);
drop type nearfeature cascade;
drop type if exists nearfeature cascade;
create type nearfeature as (
place_id BIGINT,
keywords int[],
@@ -13,7 +13,7 @@ create type nearfeature as (
isguess boolean
);
drop type nearfeaturecentr cascade;
drop type if exists nearfeaturecentr cascade;
create type nearfeaturecentr as (
place_id BIGINT,
keywords int[],
@@ -24,6 +24,16 @@ create type nearfeaturecentr as (
centroid GEOMETRY
);
drop table IF EXISTS search_name_blank CASCADE;
CREATE TABLE search_name_blank (
place_id BIGINT,
search_rank integer,
address_rank integer,
name_vector integer[]
);
SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
CREATE TABLE location_area_country () INHERITS (location_area_large);
CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry);

View File

@@ -70,7 +70,6 @@ drop table IF EXISTS word;
CREATE TABLE word (
word_id INTEGER,
word_token text,
word_trigram text,
word text,
class text,
type text,
@@ -78,9 +77,7 @@ CREATE TABLE word (
search_name_count INTEGER,
operator TEXT
);
SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
--CREATE INDEX idx_word_trigram ON word USING gin(word_trigram gin_trgm_ops) WITH (fastupdate = off);
GRANT SELECT ON word TO "www-data" ;
DROP SEQUENCE seq_word;
CREATE SEQUENCE seq_word start 1;
@@ -124,8 +121,8 @@ CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_ti
CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
GRANT SELECT ON location_property_tiger TO "www-data";
drop table IF EXISTS search_name_blank CASCADE;
CREATE TABLE search_name_blank (
drop table IF EXISTS search_name;
CREATE TABLE search_name (
place_id BIGINT,
search_rank integer,
address_rank integer,
@@ -134,10 +131,7 @@ CREATE TABLE search_name_blank (
name_vector integer[],
nameaddress_vector integer[]
);
SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
drop table IF EXISTS search_name;
CREATE TABLE search_name () INHERITS (search_name_blank);
SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
drop table IF EXISTS place_addressline;