source: subversion/applications/utils/nominatim/sql/tables-minimal.sql @ 29291

Last change on this file since 29291 was 26915, checked in by frederik, 8 years ago

fix typo mentioned by mathieu monney on mapquest's forum two weeks ago. this typo is responsible for 'location_property_tiger does not exist' errors.

File size: 5.7 KB
Line 
1drop table import_npi_log;
2CREATE TABLE import_npi_log (
3  npiid integer,
4  batchend timestamp,
5  batchsize integer,
6  starttime timestamp,
7  endtime timestamp,
8  event text
9  );
10
11drop table IF EXISTS word;
12CREATE TABLE word (
13  word_id INTEGER,
14  word_token text,
15  word_trigram text,
16  word text,
17  class text,
18  type text,
19  country_code varchar(2),
20  search_name_count INTEGER,
21  operator TEXT
22  );
23SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
24CREATE INDEX idx_word_word_id on word USING BTREE (word_id);
25CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
26GRANT SELECT ON word TO "www-data" ;
27DROP SEQUENCE seq_word;
28CREATE SEQUENCE seq_word start 1;
29
30drop table IF EXISTS location_property CASCADE;
31CREATE TABLE location_property (
32  place_id BIGINT,
33  partition integer,
34  parent_place_id BIGINT,
35  housenumber TEXT,
36  postcode TEXT
37  );
38SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
39
40CREATE TABLE location_property_aux () INHERITS (location_property);
41CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
42CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
43CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
44
45CREATE TABLE location_property_tiger () INHERITS (location_property);
46CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
47CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
48CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
49
50drop table IF EXISTS search_name_blank CASCADE;
51CREATE TABLE search_name_blank (
52  place_id BIGINT,
53  search_rank integer,
54  address_rank integer,
55  importance FLOAT,
56  country_code varchar(2),
57  name_vector integer[],
58  nameaddress_vector integer[]
59  );
60SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
61
62drop table IF EXISTS search_name;
63CREATE TABLE search_name () INHERITS (search_name_blank);
64CREATE INDEX search_name_name_vector_idx ON search_name USING GIN (name_vector gin__int_ops) WITH (fastupdate = off);
65CREATE INDEX searchnameplacesearch_search_nameaddress_vector_idx ON search_name USING GIN (nameaddress_vector gin__int_ops) WITH (fastupdate = off);
66CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
67CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
68
69drop table IF EXISTS place_addressline;
70CREATE TABLE place_addressline (
71  place_id BIGINT,
72  address_place_id BIGINT,
73  fromarea boolean,
74  isaddress boolean,
75  distance float,
76  cached_rank_address integer
77  );
78CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
79CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
80
81drop table IF EXISTS place_boundingbox CASCADE;
82CREATE TABLE place_boundingbox (
83  place_id BIGINT,
84  minlat float,
85  maxlat float,
86  minlon float,
87  maxlon float,
88  numfeatures integer,
89  area float
90  );
91CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
92SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
93CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
94GRANT SELECT on place_boundingbox to "www-data" ;
95GRANT INSERT on place_boundingbox to "www-data" ;
96
97drop table country;
98CREATE TABLE country (
99  country_code varchar(2),
100  country_name hstore,
101  country_default_language_code varchar(2)
102  );
103SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
104insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null, 
105  ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
106CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
107CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
108
109drop table placex;
110CREATE TABLE placex (
111  place_id BIGINT NOT NULL,
112  partition integer,
113  osm_type char(1),
114  osm_id INTEGER,
115  class TEXT NOT NULL,
116  type TEXT NOT NULL,
117  name HSTORE,
118  admin_level INTEGER,
119  housenumber TEXT,
120  street TEXT,
121  isin TEXT,
122  postcode TEXT,
123  country_code varchar(2),
124  extratags HSTORE,
125  parent_place_id BIGINT,
126  linked_place_id BIGINT,
127  rank_address INTEGER,
128  rank_search INTEGER,
129  importance FLOAT,
130  indexed_status INTEGER,
131  indexed_date TIMESTAMP,
132  geometry_sector INTEGER
133  );
134SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
135CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
136CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
137CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
138CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
139CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
140CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) where parent_place_id IS NOT NULL;
141
142DROP SEQUENCE seq_place;
143CREATE SEQUENCE seq_place start 1;
144GRANT SELECT on placex to "www-data" ;
145GRANT UPDATE ON placex to "www-data" ;
146GRANT SELECT ON search_name to "www-data" ;
147GRANT DELETE on search_name to "www-data" ;
148GRANT INSERT on search_name to "www-data" ;
149GRANT SELECT on place_addressline to "www-data" ;
150GRANT INSERT ON place_addressline to "www-data" ;
151GRANT DELETE on place_addressline to "www-data" ;
152GRANT SELECT ON seq_word to "www-data" ;
153GRANT UPDATE ON seq_word to "www-data" ;
154GRANT INSERT ON word to "www-data" ;
155GRANT SELECT on country to "www-data" ;
Note: See TracBrowser for help on using the repository browser.