mirror of
https://github.com/osm-search/Nominatim.git
synced 2024-12-25 14:02:12 +03:00
reorganise table creation
- remove unused tables - make apache user configurable - introduce configurable tablespaces
This commit is contained in:
parent
04a20a2a0a
commit
c391479c58
@ -5,11 +5,12 @@
|
||||
// General settings
|
||||
@define('CONST_Debug', false);
|
||||
@define('CONST_Database_DSN', 'pgsql://@/nominatim'); // <driver>://<username>:<password>@<host>:<port>/<database>
|
||||
@define('CONST_Database_Web_User', 'www-data');
|
||||
@define('CONST_Max_Word_Frequency', '50000');
|
||||
@define('CONST_Limit_Reindexing', true);
|
||||
|
||||
// Software versions
|
||||
@define('CONST_Postgresql_Version', '9.1'); // values: 8.3, 8.4, 9.0, 9.1, 9.2
|
||||
@define('CONST_Postgresql_Version', '9.1'); // values: 9.0, 9.1, 9.2
|
||||
@define('CONST_Postgis_Version', '1.5'); // values: 1.5, 2.0
|
||||
|
||||
// Paths
|
||||
@ -21,6 +22,23 @@
|
||||
// osm2pgsql settings
|
||||
@define('CONST_Osm2pgsql_Flatnode_File', null);
|
||||
|
||||
// tablespace settings
|
||||
// osm2pgsql caching tables (aka slim mode tables) - update only
|
||||
@define('CONST_Tablespace_Osm2pgsql_Data', false);
|
||||
@define('CONST_Tablespace_Osm2pgsql_Index', false);
|
||||
// osm2pgsql output tables (aka main table) - update only
|
||||
@define('CONST_Tablespace_Place_Data', false);
|
||||
@define('CONST_Tablespace_Place_Index', false);
|
||||
// address computation tables - update only
|
||||
@define('CONST_Tablespace_Address_Data', false);
|
||||
@define('CONST_Tablespace_Address_Index', false);
|
||||
// search tables - needed for lookups
|
||||
@define('CONST_Tablespace_Search_Data', false);
|
||||
@define('CONST_Tablespace_Search_Index', false);
|
||||
// additional data, e.g. TIGER data - needed for lookups
|
||||
@define('CONST_Tablespace_Aux_Data', false);
|
||||
@define('CONST_Tablespace_Aux_Index', false);
|
||||
|
||||
// Replication settings
|
||||
@define('CONST_Replication_Url', 'http://planet.openstreetmap.org/replication/minute');
|
||||
@define('CONST_Replication_MaxInterval', '3600');
|
||||
|
@ -548,21 +548,6 @@ BEGIN
|
||||
RETURN nearcountry.country_code;
|
||||
END LOOP;
|
||||
|
||||
-- WorldBoundaries data (second fallback - think there might be something broken in this data)
|
||||
-- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
|
||||
-- LOOP
|
||||
-- RETURN nearcountry.country_code;
|
||||
-- END LOOP;
|
||||
|
||||
--RAISE WARNING 'near country: %', ST_AsText(place_centre);
|
||||
|
||||
-- Still not in a country - try nearest within ~12 miles of a country
|
||||
-- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
|
||||
-- order by st_distance(geometry, place) limit 1
|
||||
-- LOOP
|
||||
-- RETURN nearcountry.country_code;
|
||||
-- END LOOP;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
@ -1329,7 +1314,6 @@ BEGIN
|
||||
|
||||
result := deleteSearchName(NEW.partition, NEW.place_id);
|
||||
DELETE FROM place_addressline WHERE place_id = NEW.place_id;
|
||||
DELETE FROM place_boundingbox where place_id = NEW.place_id;
|
||||
result := deleteRoad(NEW.partition, NEW.place_id);
|
||||
result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
|
||||
UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
|
||||
@ -1348,7 +1332,7 @@ BEGIN
|
||||
place_centroid := ST_PointOnSurface(NEW.geometry);
|
||||
NEW.centroid := null;
|
||||
|
||||
-- reclaculate country and partition
|
||||
-- recalculate country and partition
|
||||
IF NEW.rank_search = 4 THEN
|
||||
-- for countries, believe the mapped country code,
|
||||
-- so that we remain in the right partition if the boundaries
|
||||
@ -2599,86 +2583,10 @@ END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
|
||||
AS $$
|
||||
DECLARE
|
||||
result place_boundingbox;
|
||||
numfeatures integer;
|
||||
BEGIN
|
||||
select * from place_boundingbox into result where place_id = search_place_id;
|
||||
IF result.place_id IS NULL THEN
|
||||
-- remove isaddress = true because if there is a matching polygon it always wins
|
||||
select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
|
||||
insert into place_boundingbox select place_id,
|
||||
ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
|
||||
ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
|
||||
numfeatures, ST_Area(geometry),
|
||||
geometry as area from location_area where place_id = search_place_id;
|
||||
select * from place_boundingbox into result where place_id = search_place_id;
|
||||
END IF;
|
||||
IF result.place_id IS NULL THEN
|
||||
-- TODO 0.0001
|
||||
insert into place_boundingbox select address_place_id,
|
||||
min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
|
||||
min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
|
||||
count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
|
||||
ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
|
||||
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)
|
||||
where address_place_id = search_place_id
|
||||
-- and (isaddress = true OR place_id = search_place_id)
|
||||
and (st_length(geometry) < 0.01 or place_id = search_place_id)
|
||||
group by address_place_id limit 1;
|
||||
select * from place_boundingbox into result where place_id = search_place_id;
|
||||
END IF;
|
||||
return result;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
-- don't do the operation if it would be slow
|
||||
CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
|
||||
AS $$
|
||||
DECLARE
|
||||
result place_boundingbox;
|
||||
numfeatures integer;
|
||||
rank integer;
|
||||
BEGIN
|
||||
select * from place_boundingbox into result where place_id = search_place_id;
|
||||
IF result IS NULL AND rank > 14 THEN
|
||||
select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
|
||||
insert into place_boundingbox select place_id,
|
||||
ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
|
||||
ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
|
||||
numfeatures, ST_Area(geometry),
|
||||
geometry as area from location_area where place_id = search_place_id;
|
||||
select * from place_boundingbox into result where place_id = search_place_id;
|
||||
END IF;
|
||||
IF result IS NULL THEN
|
||||
select rank_search from placex where place_id = search_place_id into rank;
|
||||
IF rank > 20 THEN
|
||||
-- TODO 0.0001
|
||||
insert into place_boundingbox select address_place_id,
|
||||
min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
|
||||
min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
|
||||
count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
|
||||
ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
|
||||
from place_addressline join placex using (place_id)
|
||||
where address_place_id = search_place_id
|
||||
and (isaddress = true OR place_id = search_place_id)
|
||||
and (st_length(geometry) < 0.01 or place_id = search_place_id)
|
||||
group by address_place_id limit 1;
|
||||
select * from place_boundingbox into result where place_id = search_place_id;
|
||||
END IF;
|
||||
END IF;
|
||||
return result;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
result place_boundingbox;
|
||||
numfeatures integer;
|
||||
BEGIN
|
||||
update placex set
|
||||
|
@ -1,33 +1,30 @@
|
||||
-- Indices used only during search and update.
|
||||
-- These indices are created only after the indexing process is done.
|
||||
|
||||
CREATE INDEX idx_word_word_id on word USING BTREE (word_id);
|
||||
CREATE INDEX idx_word_word_id on word USING BTREE (word_id) {ts:search-index};
|
||||
|
||||
CREATE INDEX idx_search_name_nameaddress_vector ON search_name USING GIN (nameaddress_vector) WITH (fastupdate = off);
|
||||
CREATE INDEX idx_search_name_name_vector ON search_name USING GIN (name_vector) WITH (fastupdate = off);
|
||||
CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
|
||||
CREATE INDEX idx_search_name_nameaddress_vector ON search_name USING GIN (nameaddress_vector) WITH (fastupdate = off) {ts:search-index};
|
||||
CREATE INDEX idx_search_name_name_vector ON search_name USING GIN (name_vector) WITH (fastupdate = off) {ts:search-index};
|
||||
CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid) {ts:search-index};
|
||||
|
||||
CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
|
||||
|
||||
CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
|
||||
CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
|
||||
CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id) {ts:search-index};
|
||||
|
||||
DROP INDEX IF EXISTS idx_placex_rank_search;
|
||||
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
|
||||
CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
|
||||
CREATE INDEX idx_placex_pendingsector ON placex USING BTREE (rank_search,geometry_sector) where indexed_status > 0;
|
||||
CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) where parent_place_id IS NOT NULL;
|
||||
CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed_status > 0 and class='place' and type='houses';
|
||||
CREATE INDEX idx_placex_reverse_geometry ON placex USING gist (geometry) where rank_search != 28 and (name is not null or housenumber is not null) and class not in ('waterway','railway','tunnel','bridge');
|
||||
CREATE INDEX idx_location_area_country_place_id ON location_area_country USING BTREE (place_id);
|
||||
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search) {ts:search-index};
|
||||
CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address) {ts:search-index};
|
||||
CREATE INDEX idx_placex_pendingsector ON placex USING BTREE (rank_search,geometry_sector) {ts:address-index} where indexed_status > 0;
|
||||
CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) {ts:search-index} where parent_place_id IS NOT NULL;
|
||||
CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) {ts:address-index} where indexed_status > 0 and class='place' and type='houses';
|
||||
CREATE INDEX idx_placex_reverse_geometry ON placex USING gist (geometry) {ts:search-index} where rank_search != 28 and (name is not null or housenumber is not null) and class not in ('waterway','railway','tunnel','bridge');
|
||||
CREATE INDEX idx_location_area_country_place_id ON location_area_country USING BTREE (place_id) {ts:address-index};
|
||||
|
||||
CREATE INDEX idx_search_name_country_centroid ON search_name_country USING GIST (centroid);
|
||||
CREATE INDEX idx_search_name_country_centroid ON search_name_country USING GIST (centroid) {ts:address-index};
|
||||
|
||||
-- start
|
||||
CREATE INDEX idx_location_property_-partition-_centroid ON location_property_-partition- USING GIST (centroid);
|
||||
CREATE INDEX idx_location_property_-partition-_centroid ON location_property_-partition- USING GIST (centroid) {ts:address-index};
|
||||
-- end
|
||||
|
||||
CREATE UNIQUE INDEX idx_place_osm_unique on place using btree(osm_id,osm_type,class,type);
|
||||
CREATE UNIQUE INDEX idx_place_osm_unique on place using btree(osm_id,osm_type,class,type) {ts:address-index};
|
||||
|
||||
|
||||
CREATE INDEX idx_gb_postcode_postcode ON gb_postcode USING BTREE (postcode);
|
||||
CREATE INDEX idx_gb_postcode_postcode ON gb_postcode USING BTREE (postcode) {ts:search-index};
|
||||
|
@ -34,35 +34,35 @@ CREATE TABLE search_name_blank (
|
||||
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);
|
||||
CREATE TABLE location_area_country () INHERITS (location_area_large) {ts:address-data};
|
||||
CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts:address-index};
|
||||
|
||||
CREATE TABLE search_name_country () INHERITS (search_name_blank);
|
||||
CREATE INDEX idx_search_name_country_place_id ON search_name_country USING BTREE (place_id);
|
||||
CREATE INDEX idx_search_name_country_name_vector ON search_name_country USING GIN (name_vector) WITH (fastupdate = off);
|
||||
CREATE TABLE search_name_country () INHERITS (search_name_blank) {ts:address-data};
|
||||
CREATE INDEX idx_search_name_country_place_id ON search_name_country USING BTREE (place_id) {ts:address-index};
|
||||
CREATE INDEX idx_search_name_country_name_vector ON search_name_country USING GIN (name_vector) WITH (fastupdate = off) {ts:address-index};
|
||||
|
||||
-- start
|
||||
CREATE TABLE location_area_large_-partition- () INHERITS (location_area_large);
|
||||
CREATE INDEX idx_location_area_large_-partition-_place_id ON location_area_large_-partition- USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_area_large_-partition-_geometry ON location_area_large_-partition- USING GIST (geometry);
|
||||
CREATE TABLE location_area_large_-partition- () INHERITS (location_area_large) {ts:address-data};
|
||||
CREATE INDEX idx_location_area_large_-partition-_place_id ON location_area_large_-partition- USING BTREE (place_id) {ts:address-index};
|
||||
CREATE INDEX idx_location_area_large_-partition-_geometry ON location_area_large_-partition- USING GIST (geometry) {ts:address-index};
|
||||
|
||||
CREATE TABLE search_name_-partition- () INHERITS (search_name_blank);
|
||||
CREATE INDEX idx_search_name_-partition-_place_id ON search_name_-partition- USING BTREE (place_id);
|
||||
CREATE INDEX idx_search_name_-partition-_centroid ON search_name_-partition- USING GIST (centroid);
|
||||
CREATE INDEX idx_search_name_-partition-_name_vector ON search_name_-partition- USING GIN (name_vector) WITH (fastupdate = off);
|
||||
CREATE TABLE search_name_-partition- () INHERITS (search_name_blank) {ts:address-data};
|
||||
CREATE INDEX idx_search_name_-partition-_place_id ON search_name_-partition- USING BTREE (place_id) {ts:address-index};
|
||||
CREATE INDEX idx_search_name_-partition-_centroid ON search_name_-partition- USING GIST (centroid) {ts:address-index};
|
||||
CREATE INDEX idx_search_name_-partition-_name_vector ON search_name_-partition- USING GIN (name_vector) WITH (fastupdate = off) {ts:address-index};
|
||||
|
||||
CREATE TABLE location_property_-partition- () INHERITS (location_property);
|
||||
CREATE INDEX idx_location_property_-partition-_place_id ON location_property_-partition- USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_property_-partition-_parent_place_id ON location_property_-partition- USING BTREE (parent_place_id);
|
||||
CREATE INDEX idx_location_property_-partition-_housenumber_parent_place_id ON location_property_-partition- USING BTREE (parent_place_id, housenumber);
|
||||
CREATE TABLE location_property_-partition- () INHERITS (location_property) {ts:aux-data};
|
||||
CREATE INDEX idx_location_property_-partition-_place_id ON location_property_-partition- USING BTREE (place_id) {ts:aux-index};
|
||||
CREATE INDEX idx_location_property_-partition-_parent_place_id ON location_property_-partition- USING BTREE (parent_place_id) {ts:aux-index};
|
||||
CREATE INDEX idx_location_property_-partition-_housenumber_parent_place_id ON location_property_-partition- USING BTREE (parent_place_id, housenumber) {ts:aux-index};
|
||||
|
||||
CREATE TABLE location_road_-partition- (
|
||||
partition integer,
|
||||
place_id BIGINT,
|
||||
country_code VARCHAR(2)
|
||||
);
|
||||
) {ts:address-data};
|
||||
SELECT AddGeometryColumn('location_road_-partition-', 'geometry', 4326, 'GEOMETRY', 2);
|
||||
CREATE INDEX idx_location_road_-partition-_geometry ON location_road_-partition- USING GIST (geometry);
|
||||
CREATE INDEX idx_location_road_-partition-_place_id ON location_road_-partition- USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_road_-partition-_geometry ON location_road_-partition- USING GIST (geometry) {ts:address-index};
|
||||
CREATE INDEX idx_location_road_-partition-_place_id ON location_road_-partition- USING BTREE (place_id) {ts:address-index};
|
||||
|
||||
-- end
|
||||
|
139
sql/tables.sql
139
sql/tables.sql
@ -1,10 +1,10 @@
|
||||
drop table import_status;
|
||||
drop table if exists import_status;
|
||||
CREATE TABLE import_status (
|
||||
lastimportdate timestamp NOT NULL
|
||||
);
|
||||
GRANT SELECT ON import_status TO "www-data" ;
|
||||
GRANT SELECT ON import_status TO "{www-user}" ;
|
||||
|
||||
drop table import_osmosis_log;
|
||||
drop table if exists import_osmosis_log;
|
||||
CREATE TABLE import_osmosis_log (
|
||||
batchend timestamp,
|
||||
batchsize integer,
|
||||
@ -13,7 +13,7 @@ CREATE TABLE import_osmosis_log (
|
||||
event text
|
||||
);
|
||||
|
||||
drop table import_npi_log;
|
||||
drop table if exists import_npi_log;
|
||||
CREATE TABLE import_npi_log (
|
||||
npiid integer,
|
||||
batchend timestamp,
|
||||
@ -32,9 +32,9 @@ CREATE TABLE query_log (
|
||||
results integer
|
||||
);
|
||||
CREATE INDEX idx_query_log ON query_log USING BTREE (starttime);
|
||||
GRANT SELECT ON query_log TO "www-data" ;
|
||||
GRANT INSERT ON query_log TO "www-data" ;
|
||||
GRANT UPDATE ON query_log TO "www-data" ;
|
||||
GRANT SELECT ON query_log TO "{www-user}" ;
|
||||
GRANT INSERT ON query_log TO "{www-user}" ;
|
||||
GRANT UPDATE ON query_log TO "{www-user}" ;
|
||||
|
||||
CREATE TABLE new_query_log (
|
||||
type text,
|
||||
@ -49,23 +49,13 @@ CREATE TABLE new_query_log (
|
||||
secret text
|
||||
);
|
||||
CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
|
||||
GRANT INSERT ON new_query_log TO "www-data" ;
|
||||
GRANT UPDATE ON new_query_log TO "www-data" ;
|
||||
GRANT SELECT ON new_query_log TO "www-data" ;
|
||||
GRANT INSERT ON new_query_log TO "{www-user}" ;
|
||||
GRANT UPDATE ON new_query_log TO "{www-user}" ;
|
||||
GRANT SELECT ON new_query_log TO "{www-user}" ;
|
||||
|
||||
create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
|
||||
useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
|
||||
|
||||
--drop table IF EXISTS report_log;
|
||||
CREATE TABLE report_log (
|
||||
starttime timestamp,
|
||||
ipaddress text,
|
||||
query text,
|
||||
description text,
|
||||
email text
|
||||
);
|
||||
GRANT INSERT ON report_log TO "www-data" ;
|
||||
|
||||
drop table IF EXISTS word;
|
||||
CREATE TABLE word (
|
||||
word_id INTEGER,
|
||||
@ -76,10 +66,10 @@ CREATE TABLE word (
|
||||
country_code varchar(2),
|
||||
search_name_count INTEGER,
|
||||
operator TEXT
|
||||
);
|
||||
CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
|
||||
GRANT SELECT ON word TO "www-data" ;
|
||||
DROP SEQUENCE seq_word;
|
||||
) {ts:search-data};
|
||||
CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
|
||||
GRANT SELECT ON word TO "{www-user}" ;
|
||||
DROP SEQUENCE IF EXISTS seq_word;
|
||||
CREATE SEQUENCE seq_word start 1;
|
||||
|
||||
drop table IF EXISTS location_area CASCADE;
|
||||
@ -96,8 +86,6 @@ SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
|
||||
SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
|
||||
|
||||
CREATE TABLE location_area_large () INHERITS (location_area);
|
||||
CREATE TABLE location_area_roadnear () INHERITS (location_area);
|
||||
CREATE TABLE location_area_roadfar () INHERITS (location_area);
|
||||
|
||||
drop table IF EXISTS location_property CASCADE;
|
||||
CREATE TABLE location_property (
|
||||
@ -113,13 +101,13 @@ CREATE TABLE location_property_aux () INHERITS (location_property);
|
||||
CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
|
||||
CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
|
||||
GRANT SELECT ON location_property_aux TO "www-data";
|
||||
GRANT SELECT ON location_property_aux TO "{www-user}";
|
||||
|
||||
CREATE TABLE location_property_tiger () INHERITS (location_property);
|
||||
CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
|
||||
CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
|
||||
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";
|
||||
CREATE TABLE location_property_tiger () INHERITS (location_property) {ts:aux-data};
|
||||
CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id) {ts:aux-index};
|
||||
CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id) {ts:aux-index};
|
||||
CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber) {ts:aux-index};
|
||||
GRANT SELECT ON location_property_tiger TO "{www-user}";
|
||||
|
||||
drop table IF EXISTS search_name;
|
||||
CREATE TABLE search_name (
|
||||
@ -130,9 +118,9 @@ CREATE TABLE search_name (
|
||||
country_code varchar(2),
|
||||
name_vector integer[],
|
||||
nameaddress_vector integer[]
|
||||
);
|
||||
) {ts:search-data};
|
||||
SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
|
||||
CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
|
||||
CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
|
||||
|
||||
drop table IF EXISTS place_addressline;
|
||||
CREATE TABLE place_addressline (
|
||||
@ -142,46 +130,10 @@ CREATE TABLE place_addressline (
|
||||
isaddress boolean,
|
||||
distance float,
|
||||
cached_rank_address integer
|
||||
);
|
||||
CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
|
||||
) {ts:search-data};
|
||||
CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
|
||||
|
||||
drop table IF EXISTS place_boundingbox CASCADE;
|
||||
CREATE TABLE place_boundingbox (
|
||||
place_id BIGINT,
|
||||
minlat float,
|
||||
maxlat float,
|
||||
minlon float,
|
||||
maxlon float,
|
||||
numfeatures integer,
|
||||
area float
|
||||
);
|
||||
SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
|
||||
GRANT SELECT on place_boundingbox to "www-data" ;
|
||||
GRANT INSERT on place_boundingbox to "www-data" ;
|
||||
|
||||
drop table IF EXISTS reverse_cache;
|
||||
CREATE TABLE reverse_cache (
|
||||
latlonzoomid integer,
|
||||
country_code varchar(2),
|
||||
place_id BIGINT
|
||||
);
|
||||
GRANT SELECT on reverse_cache to "www-data" ;
|
||||
GRANT INSERT on reverse_cache to "www-data" ;
|
||||
CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
|
||||
|
||||
drop table country;
|
||||
CREATE TABLE country (
|
||||
country_code varchar(2),
|
||||
country_name hstore,
|
||||
country_default_language_code varchar(2)
|
||||
);
|
||||
SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
|
||||
insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
|
||||
ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
|
||||
CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
|
||||
CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
|
||||
|
||||
drop table placex;
|
||||
drop table if exists placex;
|
||||
CREATE TABLE placex (
|
||||
place_id BIGINT NOT NULL,
|
||||
partition integer,
|
||||
@ -196,29 +148,24 @@ CREATE TABLE placex (
|
||||
wikipedia TEXT, -- calculated wikipedia article name (language:title)
|
||||
geometry_sector INTEGER,
|
||||
calculated_country_code varchar(2)
|
||||
);
|
||||
) {ts:search-data};
|
||||
SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
|
||||
CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
|
||||
CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
|
||||
CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id);
|
||||
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector);
|
||||
CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
|
||||
CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) WHERE osm_type='N' and rank_search < 26;
|
||||
CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
|
||||
CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
|
||||
CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index};
|
||||
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
|
||||
CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
|
||||
CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) WHERE osm_type='N' and rank_search < 26 {ts:address-index};
|
||||
|
||||
--CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
|
||||
|
||||
--CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search) where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
|
||||
|
||||
DROP SEQUENCE seq_place;
|
||||
DROP SEQUENCE IF EXISTS seq_place;
|
||||
CREATE SEQUENCE seq_place start 1;
|
||||
GRANT SELECT on placex to "www-data" ;
|
||||
GRANT SELECT ON search_name to "www-data" ;
|
||||
GRANT SELECT on place_addressline to "www-data" ;
|
||||
GRANT SELECT ON seq_word to "www-data" ;
|
||||
GRANT SELECT ON planet_osm_ways to "www-data" ;
|
||||
GRANT SELECT ON planet_osm_rels to "www-data" ;
|
||||
GRANT SELECT on location_area to "www-data" ;
|
||||
GRANT SELECT on country to "www-data" ;
|
||||
GRANT SELECT on placex to "{www-user}" ;
|
||||
GRANT SELECT ON search_name to "{www-user}" ;
|
||||
GRANT SELECT on place_addressline to "{www-user}" ;
|
||||
GRANT SELECT ON seq_word to "{www-user}" ;
|
||||
GRANT SELECT ON planet_osm_ways to "{www-user}" ;
|
||||
GRANT SELECT ON planet_osm_rels to "{www-user}" ;
|
||||
GRANT SELECT on location_area to "{www-user}" ;
|
||||
|
||||
-- insert creates the location tagbles, creates location indexes if indexed == true
|
||||
CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
|
||||
@ -237,7 +184,7 @@ CREATE TRIGGER place_before_insert BEFORE INSERT ON place
|
||||
FOR EACH ROW EXECUTE PROCEDURE place_insert();
|
||||
|
||||
drop index idx_placex_sector;
|
||||
CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
|
||||
CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id) {ts:address-index};
|
||||
|
||||
DROP SEQUENCE seq_postcodes;
|
||||
CREATE SEQUENCE seq_postcodes start 1;
|
||||
@ -256,7 +203,7 @@ CREATE TABLE import_polygon_error (
|
||||
SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
|
||||
SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
|
||||
CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
|
||||
GRANT SELECT ON import_polygon_error TO "www-data";
|
||||
GRANT SELECT ON import_polygon_error TO "{www-user}";
|
||||
|
||||
drop table import_polygon_delete;
|
||||
CREATE TABLE import_polygon_delete (
|
||||
@ -266,7 +213,7 @@ CREATE TABLE import_polygon_delete (
|
||||
type TEXT NOT NULL
|
||||
);
|
||||
CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
|
||||
GRANT SELECT ON import_polygon_delete TO "www-data";
|
||||
GRANT SELECT ON import_polygon_delete TO "{www-user}";
|
||||
|
||||
drop sequence file;
|
||||
CREATE SEQUENCE file start 1;
|
||||
|
@ -191,6 +191,14 @@
|
||||
{
|
||||
$osm2pgsql .= ' --flat-nodes '.CONST_Osm2pgsql_Flatnode_File;
|
||||
}
|
||||
if (CONST_Tablespace_Osm2pgsql_Data)
|
||||
$osm2pgsql .= ' --tablespace-slim-data '.CONST_Tablespace_Osm2pgsql_Data;
|
||||
if (CONST_Tablespace_Osm2pgsql_Index)
|
||||
$osm2pgsql .= ' --tablespace-slim-index '.CONST_Tablespace_Osm2pgsql_Index;
|
||||
if (CONST_Tablespace_Place_Data)
|
||||
$osm2pgsql .= ' --tablespace-main-data '.CONST_Tablespace_Place_Data;
|
||||
if (CONST_Tablespace_Place_Index)
|
||||
$osm2pgsql .= ' --tablespace-main-index '.CONST_Tablespace_Place_Index;
|
||||
$osm2pgsql .= ' -lsc -O gazetteer --hstore';
|
||||
$osm2pgsql .= ' -C '.$iCacheMemory;
|
||||
$osm2pgsql .= ' -P '.$aDSNInfo['port'];
|
||||
@ -216,6 +224,7 @@
|
||||
if ($aCMDResult['enable-debug-statements']) $sTemplate = str_replace('--DEBUG:', '', $sTemplate);
|
||||
if (CONST_Limit_Reindexing) $sTemplate = str_replace('--LIMIT INDEXING:', '', $sTemplate);
|
||||
pgsqlRunScript($sTemplate);
|
||||
|
||||
if ($fPostgisVersion < 2.0) {
|
||||
echo "Helper functions for postgis < 2.0\n";
|
||||
$sTemplate = file_get_contents(CONST_BasePath.'/sql/postgis_15_aux.sql');
|
||||
@ -258,13 +267,30 @@
|
||||
|
||||
if ($aCMDResult['create-tables'] || $aCMDResult['all'])
|
||||
{
|
||||
echo "Tables\n";
|
||||
$bDidSomething = true;
|
||||
pgsqlRunScriptFile(CONST_BasePath.'/sql/tables.sql');
|
||||
|
||||
echo "Tables\n";
|
||||
$sTemplate = file_get_contents(CONST_BasePath.'/sql/tables.sql');
|
||||
$sTemplate = str_replace('{www-user}', CONST_Database_Web_User, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:address-data}',
|
||||
CONST_Tablespace_Address_Data, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:address-index}',
|
||||
CONST_Tablespace_Address_Index, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:search-data}',
|
||||
CONST_Tablespace_Search_Data, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:search-index}',
|
||||
CONST_Tablespace_Search_Index, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:aux-data}',
|
||||
CONST_Tablespace_Aux_Data, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:aux-index}',
|
||||
CONST_Tablespace_Aux_Index, $sTemplate);
|
||||
pgsqlRunScript($sTemplate, false);
|
||||
|
||||
// re-run the functions
|
||||
echo "Functions\n";
|
||||
$sTemplate = file_get_contents(CONST_BasePath.'/sql/functions.sql');
|
||||
$sTemplate = str_replace('{modulepath}',CONST_BasePath.'/module', $sTemplate);
|
||||
$sTemplate = str_replace('{modulepath}',
|
||||
CONST_BasePath.'/module', $sTemplate);
|
||||
pgsqlRunScript($sTemplate);
|
||||
}
|
||||
|
||||
@ -282,6 +308,18 @@
|
||||
if (!$aCMDResult['no-partitions']) $aPartitions[] = 0;
|
||||
|
||||
$sTemplate = file_get_contents(CONST_BasePath.'/sql/partition-tables.src.sql');
|
||||
$sTemplate = replace_tablespace('{ts:address-data}',
|
||||
CONST_Tablespace_Address_Data, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:address-index}',
|
||||
CONST_Tablespace_Address_Index, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:search-data}',
|
||||
CONST_Tablespace_Search_Data, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:search-index}',
|
||||
CONST_Tablespace_Search_Index, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:aux-data}',
|
||||
CONST_Tablespace_Aux_Data, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:aux-index}',
|
||||
CONST_Tablespace_Aux_Index, $sTemplate);
|
||||
preg_match_all('#^-- start(.*?)^-- end#ms', $sTemplate, $aMatches, PREG_SET_ORDER);
|
||||
foreach($aMatches as $aMatch)
|
||||
{
|
||||
@ -656,6 +694,12 @@
|
||||
if (!$aCMDResult['no-partitions']) $aPartitions[] = 0;
|
||||
|
||||
$sTemplate = file_get_contents(CONST_BasePath.'/sql/indices.src.sql');
|
||||
$sTemplate = replace_tablespace('{ts:address-index}',
|
||||
CONST_Tablespace_Address_Index, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:search-index}',
|
||||
CONST_Tablespace_Search_Index, $sTemplate);
|
||||
$sTemplate = replace_tablespace('{ts:aux-index}',
|
||||
CONST_Tablespace_Aux_Index, $sTemplate);
|
||||
preg_match_all('#^-- start(.*?)^-- end#ms', $sTemplate, $aMatches, PREG_SET_ORDER);
|
||||
foreach($aMatches as $aMatch)
|
||||
{
|
||||
@ -767,14 +811,14 @@
|
||||
|
||||
}
|
||||
|
||||
function pgsqlRunScript($sScript)
|
||||
function pgsqlRunScript($sScript, $bfatal = true)
|
||||
{
|
||||
global $aCMDResult;
|
||||
// Convert database DSN to psql parameters
|
||||
$aDSNInfo = DB::parseDSN(CONST_Database_DSN);
|
||||
if (!isset($aDSNInfo['port']) || !$aDSNInfo['port']) $aDSNInfo['port'] = 5432;
|
||||
$sCMD = 'psql -p '.$aDSNInfo['port'].' -d '.$aDSNInfo['database'];
|
||||
if (!$aCMDResult['ignore-errors'])
|
||||
if ($bfatal && !$aCMDResult['ignore-errors'])
|
||||
$sCMD .= ' -v ON_ERROR_STOP=1';
|
||||
$aDescriptors = array(
|
||||
0 => array('pipe', 'r'),
|
||||
@ -793,7 +837,7 @@
|
||||
}
|
||||
fclose($ahPipes[0]);
|
||||
$iReturn = proc_close($hProcess);
|
||||
if ($iReturn > 0)
|
||||
if ($bfatal && $iReturn > 0)
|
||||
{
|
||||
fail("pgsql returned with error code ($iReturn)");
|
||||
}
|
||||
@ -861,3 +905,15 @@
|
||||
passthru($cmd, $result);
|
||||
if ($result != 0) fail('Error executing external command: '.$cmd);
|
||||
}
|
||||
|
||||
function replace_tablespace($sTemplate, $sTablespace, $sSql)
|
||||
{
|
||||
if ($sTablespace)
|
||||
$sSql = str_replace($sTemplate, 'TABLESPACE "'.$sTablespace.'"',
|
||||
$sSql);
|
||||
else
|
||||
$sSql = str_replace($sTemplate, '', $sSql);
|
||||
|
||||
return $sSql;
|
||||
}
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user