Initial commit.
This commit is contained in:
51
script/contrib/CreateGeometryForWays.sql
Normal file
51
script/contrib/CreateGeometryForWays.sql
Normal file
@@ -0,0 +1,51 @@
|
||||
-------------------------------------------------------------------------------
|
||||
-- The following script creates a new table for the pgsql simple schema for
|
||||
-- storing full way geometries.
|
||||
--
|
||||
-- Author: Ralf
|
||||
-------------------------------------------------------------------------------
|
||||
|
||||
|
||||
-- drop table if it exists
|
||||
DROP TABLE IF EXISTS way_geometry;
|
||||
|
||||
-- create table
|
||||
CREATE TABLE way_geometry(
|
||||
way_id bigint NOT NULL
|
||||
);
|
||||
-- add PostGIS geometry column
|
||||
SELECT AddGeometryColumn('', 'way_geometry', 'geom', 4326, 'GEOMETRY', 2);
|
||||
|
||||
|
||||
|
||||
-------------------------------------------------------------------------------
|
||||
-- the following might go into the POST_LOAD_SQL-array in the class "PostgreSqlWriter"??
|
||||
-------------------------------------------------------------------------------
|
||||
|
||||
-- add a linestring for every way (create a polyline)
|
||||
INSERT INTO way_geometry select id, ( select ST_LineFromMultiPoint( Collect(nodes.geom) ) from nodes
|
||||
left join way_nodes on nodes.id=way_nodes.node_id where way_nodes.way_id=ways.id ) FROM ways;
|
||||
|
||||
-- after creating a line for every way (polyline), we want closed ways to be stored as polygones.
|
||||
-- So we need to delete the previously created polylines for these ways first.
|
||||
DELETE FROM way_geometry WHERE way_id IN
|
||||
( SELECT ways.id FROM ways
|
||||
WHERE ST_IsClosed( (SELECT ST_LineFromMultiPoint( Collect(n.geom) ) FROM nodes n LEFT JOIN way_nodes wn ON n.id=wn.node_id WHERE ways.id=wn.way_id) )
|
||||
AND ST_NumPoints( (SELECT ST_LineFromMultiPoint( Collect(n.geom) ) FROM nodes n LEFT JOIN way_nodes wn ON n.id=wn.node_id WHERE ways.id=wn.way_id) ) >= 3
|
||||
)
|
||||
;
|
||||
|
||||
-- now we need to add the polyline geometry for every closed way
|
||||
INSERT INTO way_geometry SELECT ways.id,
|
||||
( SELECT ST_MakePolygon( ST_LineFromMultiPoint(Collect(nodes.geom)) ) FROM nodes
|
||||
LEFT JOIN way_nodes ON nodes.id=way_nodes.node_id WHERE way_nodes.way_id=ways.id
|
||||
)
|
||||
FROM ways
|
||||
WHERE ST_IsClosed( (SELECT ST_LineFromMultiPoint( Collect(n.geom) ) FROM nodes n LEFT JOIN way_nodes wn ON n.id=wn.node_id WHERE ways.id=wn.way_id) )
|
||||
AND ST_NumPoints( (SELECT ST_LineFromMultiPoint( Collect(n.geom) ) FROM nodes n LEFT JOIN way_nodes wn ON n.id=wn.node_id WHERE ways.id=wn.way_id) ) >= 3
|
||||
;
|
||||
-------------------------------------------------------------------------------
|
||||
|
||||
-- create index on way_geometry
|
||||
CREATE INDEX idx_way_geometry_way_id ON way_geometry USING btree (way_id);
|
||||
CREATE INDEX idx_way_geometry_geom ON way_geometry USING gist (geom);
|
4096
script/contrib/apidb_0.6.sql
Normal file
4096
script/contrib/apidb_0.6.sql
Normal file
File diff suppressed because it is too large
Load Diff
28
script/contrib/apidb_0.6_osmosis_xid_indexing.sql
Normal file
28
script/contrib/apidb_0.6_osmosis_xid_indexing.sql
Normal file
@@ -0,0 +1,28 @@
|
||||
-- This script creates a function and indexes that allow osmosis to efficiently query based on transaction ids.
|
||||
CREATE OR REPLACE FUNCTION xid_to_int4(t xid)
|
||||
RETURNS integer AS
|
||||
$BODY$
|
||||
DECLARE
|
||||
tl bigint;
|
||||
ti int;
|
||||
BEGIN
|
||||
tl := t;
|
||||
|
||||
IF tl >= 2147483648 THEN
|
||||
tl := tl - 4294967296;
|
||||
END IF;
|
||||
|
||||
ti := tl;
|
||||
|
||||
RETURN ti;
|
||||
END;
|
||||
$BODY$
|
||||
LANGUAGE 'plpgsql' IMMUTABLE STRICT;
|
||||
|
||||
|
||||
DROP INDEX IF EXISTS nodes_xmin_idx;
|
||||
DROP INDEX IF EXISTS ways_xmin_idx;
|
||||
DROP INDEX IF EXISTS relations_xmin_idx;
|
||||
CREATE INDEX nodes_xmin_idx ON nodes USING btree ((xid_to_int4(xmin)));
|
||||
CREATE INDEX ways_xmin_idx ON ways USING btree ((xid_to_int4(xmin)));
|
||||
CREATE INDEX relations_xmin_idx ON relations USING btree ((xid_to_int4(xmin)));
|
2
script/contrib/dump_apidb.sh
Executable file
2
script/contrib/dump_apidb.sh
Executable file
@@ -0,0 +1,2 @@
|
||||
#!/bin/sh
|
||||
/usr/bin/pg_dump -O -v -f "apidb_0.6.sql" api06
|
37
script/contrib/replicate_osm_file.sh
Executable file
37
script/contrib/replicate_osm_file.sh
Executable file
@@ -0,0 +1,37 @@
|
||||
#!/bin/sh
|
||||
|
||||
# This script automates the replication of changes into an offline osm file for a specific area of interest. This allows an up-to-date local snapshot of an area to be maintained.
|
||||
|
||||
# The name of the replicated file.
|
||||
OSM_FILE=myfile.osm.gz
|
||||
|
||||
# The name of the temp file to create during processing (Note: must have the same extension as OSM_FILE to ensure the same compression method is used.
|
||||
TEMP_OSM_FILE=tmp.osm.gz
|
||||
|
||||
# The directory containing the state associated with the --read-change-interval task previously initiated with the --read-change-interval-init task.
|
||||
WORKING_DIRECTORY=./
|
||||
|
||||
# The bounding box to maintain.
|
||||
LEFT=-180
|
||||
BOTTOM=-90
|
||||
RIGHT=180
|
||||
TOP=90
|
||||
|
||||
# The osmosis command.
|
||||
CMD="osmosis -q"
|
||||
|
||||
# Launch the osmosis process.
|
||||
$CMD --read-change-interval $WORKING_DIRECTORY --read-xml $OSM_FILE --apply-change --bounding-box left=$LEFT bottom=$BOTTOM right=$RIGHT top=$TOP --write-xml $TEMP_OSM_FILE
|
||||
|
||||
STATUS=$?
|
||||
|
||||
# Verify that osmosis ran successfully.
|
||||
if [ "$STATUS" -ne "0" ]; then
|
||||
|
||||
echo "Osmosis failed, aborting."
|
||||
exit $STATUS
|
||||
|
||||
fi
|
||||
|
||||
mv $TEMP_OSM_FILE $OSM_FILE
|
||||
|
14
script/fix_line_endings.sh
Executable file
14
script/fix_line_endings.sh
Executable file
@@ -0,0 +1,14 @@
|
||||
#!/bin/sh
|
||||
|
||||
find . -iname "*.java" -exec dos2unix -U '{}' \;
|
||||
find . -iname "*.xml" -exec dos2unix -U '{}' \;
|
||||
find . -iname "*.txt" -exec dos2unix -U '{}' \;
|
||||
find . -iname "*.osm" -exec dos2unix -U '{}' \;
|
||||
find . -iname "*.osc" -exec dos2unix -U '{}' \;
|
||||
|
||||
find . -iname "*.java" -exec svn propset svn:eol-style native '{}' \;
|
||||
find . -iname "*.xml" -exec svn propset svn:eol-style native '{}' \;
|
||||
find . -iname "*.txt" -exec svn propset svn:eol-style native '{}' \;
|
||||
find . -iname "*.osm" -exec svn propset svn:eol-style native '{}' \;
|
||||
find . -iname "*.osc" -exec svn propset svn:eol-style native '{}' \;
|
||||
|
7
script/munin/README
Normal file
7
script/munin/README
Normal file
@@ -0,0 +1,7 @@
|
||||
to activate the munin plugins
|
||||
- copy "osm_replication_lag" to "/usr/share/munin/plugins"
|
||||
- make "/usr/share/munin/plugins/osm_replication_lag" executable
|
||||
- symlink "/usr/share/munin/plugins/osm_replication_lag" to "/etc/munin/plugins"
|
||||
- copy "osm_replication.conf" to "/etc/munin/plugin-conf.d"
|
||||
- edit "/etc/munin/plugin-conf.d/osm_replication.conf" and set the workingDirectory
|
||||
- restart the munin-node
|
15
script/munin/osm_replication.conf
Normal file
15
script/munin/osm_replication.conf
Normal file
@@ -0,0 +1,15 @@
|
||||
[osm*]
|
||||
|
||||
# the osmosis invocation may take some time
|
||||
timeout 60
|
||||
|
||||
# the system user that has access to the working directory, if it'S different
|
||||
# from "munin"
|
||||
#user osm
|
||||
|
||||
# path to the osmosis binary. if not set, osmosis is assumed to be in $PATH
|
||||
#env.osmosis /opt/osmosis/bin/osmosis
|
||||
|
||||
# working directory of the osmosis replication.
|
||||
# this must be set to make the munin plugin work
|
||||
#env.workingDirectory /path/to/state.txt
|
35
script/munin/osm_replication_lag
Executable file
35
script/munin/osm_replication_lag
Executable file
@@ -0,0 +1,35 @@
|
||||
#!/bin/sh
|
||||
# -*- sh -*-
|
||||
|
||||
# load the munin plugin helper
|
||||
. $MUNIN_LIBDIR/plugins/plugin.sh
|
||||
|
||||
# if no workingDirectory has been configures
|
||||
if [ ! $workingDirectory ]; then
|
||||
# exit with an error
|
||||
echo "no workingDirectory configured" >&2
|
||||
exit 1
|
||||
fi
|
||||
|
||||
# path to osmosis binary
|
||||
[ $osmosis ] || osmosis="osmosis"
|
||||
|
||||
# configuration section
|
||||
if [ "$1" = "config" ]; then
|
||||
|
||||
echo 'graph_title OSM PostGIS Database Replag'
|
||||
echo 'graph_args --base 1000'
|
||||
echo 'graph_vlabel seconds behind main database'
|
||||
echo 'graph_category osm'
|
||||
|
||||
echo 'lag.label replication lag'
|
||||
echo 'lag.draw LINE'
|
||||
|
||||
exit 0
|
||||
fi
|
||||
|
||||
# invoke osmosis to calculate the replication lag
|
||||
lag=$($osmosis --read-replication-lag workingDirectory="$workingDirectory" 2>/dev/null)
|
||||
echo "lag.value $lag"
|
||||
|
||||
exit 0
|
67
script/pgsimple_load_0.6.sql
Normal file
67
script/pgsimple_load_0.6.sql
Normal file
@@ -0,0 +1,67 @@
|
||||
-- Drop all primary keys and indexes to improve load speed.
|
||||
ALTER TABLE nodes DROP CONSTRAINT pk_nodes;
|
||||
ALTER TABLE ways DROP CONSTRAINT pk_ways;
|
||||
ALTER TABLE way_nodes DROP CONSTRAINT pk_way_nodes;
|
||||
ALTER TABLE relations DROP CONSTRAINT pk_relations;
|
||||
ALTER TABLE relation_members DROP CONSTRAINT pk_relation_members;
|
||||
DROP INDEX idx_node_tags_node_id;
|
||||
DROP INDEX idx_nodes_geom;
|
||||
DROP INDEX idx_way_tags_way_id;
|
||||
DROP INDEX idx_way_nodes_node_id;
|
||||
DROP INDEX idx_relation_tags_relation_id;
|
||||
DROP INDEX idx_ways_bbox;
|
||||
DROP INDEX idx_ways_linestring;
|
||||
|
||||
-- Comment these out if the COPY files include bbox or linestring column values.
|
||||
SELECT DropGeometryColumn('ways', 'bbox');
|
||||
SELECT DropGeometryColumn('ways', 'linestring');
|
||||
|
||||
-- Import the table data from the data files using the fast COPY method.
|
||||
\copy users FROM 'users.txt'
|
||||
\copy nodes FROM 'nodes.txt'
|
||||
\copy node_tags FROM 'node_tags.txt'
|
||||
\copy ways FROM 'ways.txt'
|
||||
\copy way_tags FROM 'way_tags.txt'
|
||||
\copy way_nodes FROM 'way_nodes.txt'
|
||||
\copy relations FROM 'relations.txt'
|
||||
\copy relation_tags FROM 'relation_tags.txt'
|
||||
\copy relation_members FROM 'relation_members.txt'
|
||||
|
||||
-- Add the primary keys and indexes back again (except the way bbox index).
|
||||
ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id);
|
||||
ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id);
|
||||
ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id);
|
||||
ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id);
|
||||
ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id);
|
||||
CREATE INDEX idx_node_tags_node_id ON node_tags USING btree (node_id);
|
||||
CREATE INDEX idx_nodes_geom ON nodes USING gist (geom);
|
||||
CREATE INDEX idx_way_tags_way_id ON way_tags USING btree (way_id);
|
||||
CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id);
|
||||
CREATE INDEX idx_relation_tags_relation_id ON relation_tags USING btree (relation_id);
|
||||
|
||||
-- Comment these out if the COPY files include bbox or linestring column values.
|
||||
SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2);
|
||||
SELECT AddGeometryColumn('ways', 'linestring', 4326, 'GEOMETRY', 2);
|
||||
|
||||
-- Comment these out if the COPY files include bbox or linestring column values.
|
||||
-- Update the bbox column of the way table.
|
||||
UPDATE ways SET bbox = (
|
||||
SELECT ST_Envelope(ST_Collect(geom))
|
||||
FROM nodes JOIN way_nodes ON way_nodes.node_id = nodes.id
|
||||
WHERE way_nodes.way_id = ways.id
|
||||
);
|
||||
-- Update the linestring column of the way table.
|
||||
UPDATE ways w SET linestring = (
|
||||
SELECT ST_MakeLine(c.geom) AS way_line FROM (
|
||||
SELECT n.geom AS geom
|
||||
FROM nodes n INNER JOIN way_nodes wn ON n.id = wn.node_id
|
||||
WHERE (wn.way_id = w.id) ORDER BY wn.sequence_id
|
||||
) c
|
||||
)
|
||||
|
||||
-- Index the way bounding box column.
|
||||
CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);
|
||||
CREATE INDEX idx_ways_linestring ON ways USING gist (linestring);
|
||||
|
||||
-- Perform database maintenance due to large database changes.
|
||||
VACUUM ANALYZE;
|
141
script/pgsimple_schema_0.6.sql
Normal file
141
script/pgsimple_schema_0.6.sql
Normal file
@@ -0,0 +1,141 @@
|
||||
-- Database creation script for the simple PostgreSQL schema.
|
||||
|
||||
-- Drop all tables if they exist.
|
||||
DROP TABLE IF EXISTS actions;
|
||||
DROP TABLE IF EXISTS users;
|
||||
DROP TABLE IF EXISTS nodes;
|
||||
DROP TABLE IF EXISTS node_tags;
|
||||
DROP TABLE IF EXISTS ways;
|
||||
DROP TABLE IF EXISTS way_nodes;
|
||||
DROP TABLE IF EXISTS way_tags;
|
||||
DROP TABLE IF EXISTS relations;
|
||||
DROP TABLE IF EXISTS relation_members;
|
||||
DROP TABLE IF EXISTS relation_tags;
|
||||
DROP TABLE IF EXISTS schema_info;
|
||||
|
||||
-- Drop all stored procedures if they exist.
|
||||
DROP FUNCTION IF EXISTS osmosisUpdate();
|
||||
|
||||
|
||||
-- Create a table which will contain a single row defining the current schema version.
|
||||
CREATE TABLE schema_info (
|
||||
version integer NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for users.
|
||||
CREATE TABLE users (
|
||||
id int NOT NULL,
|
||||
name text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for nodes.
|
||||
CREATE TABLE nodes (
|
||||
id bigint NOT NULL,
|
||||
version int NOT NULL,
|
||||
user_id int NOT NULL,
|
||||
tstamp timestamp without time zone NOT NULL,
|
||||
changeset_id bigint NOT NULL
|
||||
);
|
||||
-- Add a postgis point column holding the location of the node.
|
||||
SELECT AddGeometryColumn('nodes', 'geom', 4326, 'POINT', 2);
|
||||
|
||||
|
||||
-- Create a table for node tags.
|
||||
CREATE TABLE node_tags (
|
||||
node_id bigint NOT NULL,
|
||||
k text NOT NULL,
|
||||
v text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for ways.
|
||||
CREATE TABLE ways (
|
||||
id bigint NOT NULL,
|
||||
version int NOT NULL,
|
||||
user_id int NOT NULL,
|
||||
tstamp timestamp without time zone NOT NULL,
|
||||
changeset_id bigint NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for representing way to node relationships.
|
||||
CREATE TABLE way_nodes (
|
||||
way_id bigint NOT NULL,
|
||||
node_id bigint NOT NULL,
|
||||
sequence_id int NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for way tags.
|
||||
CREATE TABLE way_tags (
|
||||
way_id bigint NOT NULL,
|
||||
k text NOT NULL,
|
||||
v text
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for relations.
|
||||
CREATE TABLE relations (
|
||||
id bigint NOT NULL,
|
||||
version int NOT NULL,
|
||||
user_id int NOT NULL,
|
||||
tstamp timestamp without time zone NOT NULL,
|
||||
changeset_id bigint NOT NULL
|
||||
);
|
||||
|
||||
-- Create a table for representing relation member relationships.
|
||||
CREATE TABLE relation_members (
|
||||
relation_id bigint NOT NULL,
|
||||
member_id bigint NOT NULL,
|
||||
member_type character(1) NOT NULL,
|
||||
member_role text NOT NULL,
|
||||
sequence_id int NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for relation tags.
|
||||
CREATE TABLE relation_tags (
|
||||
relation_id bigint NOT NULL,
|
||||
k text NOT NULL,
|
||||
v text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Configure the schema version.
|
||||
INSERT INTO schema_info (version) VALUES (5);
|
||||
|
||||
|
||||
-- Add primary keys to tables.
|
||||
ALTER TABLE ONLY schema_info ADD CONSTRAINT pk_schema_info PRIMARY KEY (version);
|
||||
|
||||
ALTER TABLE ONLY users ADD CONSTRAINT pk_users PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id);
|
||||
|
||||
ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id);
|
||||
|
||||
|
||||
-- Add indexes to tables.
|
||||
CREATE INDEX idx_node_tags_node_id ON node_tags USING btree (node_id);
|
||||
CREATE INDEX idx_nodes_geom ON nodes USING gist (geom);
|
||||
|
||||
CREATE INDEX idx_way_tags_way_id ON way_tags USING btree (way_id);
|
||||
CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id);
|
||||
|
||||
CREATE INDEX idx_relation_tags_relation_id ON relation_tags USING btree (relation_id);
|
||||
|
||||
|
||||
-- Create stored procedures.
|
||||
CREATE FUNCTION osmosisUpdate() RETURNS void AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
15
script/pgsimple_schema_0.6_action.sql
Normal file
15
script/pgsimple_schema_0.6_action.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
-- Add an action table for the purpose of capturing all actions applied to a database.
|
||||
-- The table is populated during application of a changeset, then osmosisUpdate is called,
|
||||
-- then the table is cleared all within a single database transaction.
|
||||
-- The contents of this table can be used to update derivative tables by customising the
|
||||
-- osmosisUpdate stored procedure.
|
||||
|
||||
-- Create a table for actions.
|
||||
CREATE TABLE actions (
|
||||
data_type character(1) NOT NULL,
|
||||
action character(1) NOT NULL,
|
||||
id bigint NOT NULL
|
||||
);
|
||||
|
||||
-- Add primary key.
|
||||
ALTER TABLE ONLY actions ADD CONSTRAINT pk_actions PRIMARY KEY (data_type, id);
|
6
script/pgsimple_schema_0.6_bbox.sql
Normal file
6
script/pgsimple_schema_0.6_bbox.sql
Normal file
@@ -0,0 +1,6 @@
|
||||
-- Add a postgis GEOMETRY column to the way table for the purpose of indexing the location of the way.
|
||||
-- This will contain a bounding box surrounding the extremities of the way.
|
||||
SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2);
|
||||
|
||||
-- Add an index to the bbox column.
|
||||
CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);
|
5
script/pgsimple_schema_0.6_linestring.sql
Normal file
5
script/pgsimple_schema_0.6_linestring.sql
Normal file
@@ -0,0 +1,5 @@
|
||||
-- Add a postgis GEOMETRY column to the way table for the purpose of storing the full linestring of the way.
|
||||
SELECT AddGeometryColumn('ways', 'linestring', 4326, 'GEOMETRY', 2);
|
||||
|
||||
-- Add an index to the bbox column.
|
||||
CREATE INDEX idx_ways_linestring ON ways USING gist (linestring);
|
18
script/pgsnapshot_and_pgsimple.txt
Normal file
18
script/pgsnapshot_and_pgsimple.txt
Normal file
@@ -0,0 +1,18 @@
|
||||
Both the pgsimple and pgsnapshot schemas are PostgreSQL schemas utilising postgis extensions that are capable of storing snapshots of OSM data.
|
||||
No history is maintained.
|
||||
They can be populated by osmosis and kept up to date with osmosis daily, hourly and minute changesets.
|
||||
|
||||
The pgsimple and pgsnapshot schemas are forked versions of the same schema.
|
||||
Up to version 5 of the schema they were known as the "simple" schema.
|
||||
The pgsimple schema is the "simple" schema and is unchanged.
|
||||
Since version 6, the pgsnapshot schema has deviated to include all tag information in hstore "tags" columns inside the parent entity tables.
|
||||
|
||||
The purpose of the pgsimple schema is to provide a simplistic and generic schema for storing OSM data in a PostGIS format.
|
||||
The purpose of the pgsnapshot schema is similar but maximises performance through CLUSTERed indexes and embedded tag data. It imposes additional programming complexity.
|
||||
|
||||
The following scripts are available for both schemas:
|
||||
pgxxx_schema_0.x.sql - The schema creation script.
|
||||
pgxxx_schema_0.x_bbox.sql - A script for adding way bbox column support.
|
||||
pgxxx_schema_0.x_linestring.sql - A script for adding way linestring column support.
|
||||
pgxxx_schema_0.x_action.sql - A script for adding an action table which is populated during changeset processing to allow derivative tables to be kept up to date.
|
||||
pgxxx_load_0.x.sql - A script for importing PostgreSQL "COPY" files as produced by the osmosis --write-pgxxx-dump tasks.
|
82
script/pgsnapshot_load_0.6.sql
Normal file
82
script/pgsnapshot_load_0.6.sql
Normal file
@@ -0,0 +1,82 @@
|
||||
-- Allow data loss (but not corruption) in the case of a power outage. This is okay because we need to re-run the script anyways.
|
||||
SET synchronous_commit TO OFF;
|
||||
|
||||
-- Drop all primary keys and indexes to improve load speed.
|
||||
ALTER TABLE nodes DROP CONSTRAINT pk_nodes;
|
||||
ALTER TABLE ways DROP CONSTRAINT pk_ways;
|
||||
ALTER TABLE way_nodes DROP CONSTRAINT pk_way_nodes;
|
||||
ALTER TABLE relations DROP CONSTRAINT pk_relations;
|
||||
ALTER TABLE relation_members DROP CONSTRAINT pk_relation_members;
|
||||
DROP INDEX idx_nodes_geom;
|
||||
DROP INDEX idx_way_nodes_node_id;
|
||||
DROP INDEX idx_relation_members_member_id_and_type;
|
||||
DROP INDEX idx_ways_bbox;
|
||||
DROP INDEX idx_ways_linestring;
|
||||
|
||||
-- Uncomment these out if bbox or linestring columns are needed and the COPY
|
||||
-- files do not include them. If you want these columns you should use the
|
||||
-- enableBboxBuilder or enableLinestringBuilder options to --write-pgsql-dump
|
||||
-- as they are faster than the following SQL.
|
||||
|
||||
/*SELECT DropGeometryColumn('ways', 'bbox');
|
||||
SELECT DropGeometryColumn('ways', 'linestring');*/
|
||||
|
||||
-- Import the table data from the data files using the fast COPY method.
|
||||
\copy users FROM 'users.txt'
|
||||
\copy nodes FROM 'nodes.txt'
|
||||
\copy ways FROM 'ways.txt'
|
||||
\copy way_nodes FROM 'way_nodes.txt'
|
||||
\copy relations FROM 'relations.txt'
|
||||
\copy relation_members FROM 'relation_members.txt'
|
||||
|
||||
-- Add the primary keys and indexes back again (except the way bbox index).
|
||||
ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id);
|
||||
ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id);
|
||||
ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id);
|
||||
ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id);
|
||||
ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id);
|
||||
CREATE INDEX idx_nodes_geom ON nodes USING gist (geom);
|
||||
CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id);
|
||||
CREATE INDEX idx_relation_members_member_id_and_type ON relation_members USING btree (member_id, member_type);
|
||||
|
||||
ALTER TABLE ONLY nodes CLUSTER ON idx_nodes_geom;
|
||||
ALTER TABLE ONLY way_nodes CLUSTER ON pk_way_nodes;
|
||||
ALTER TABLE ONLY relation_members CLUSTER ON pk_relation_members;
|
||||
|
||||
-- Uncomment these if bbox or linestring columns are needed and the COPY files do not include them.
|
||||
|
||||
-- Update the bbox column of the way table.
|
||||
/*SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2);
|
||||
UPDATE ways SET bbox = (
|
||||
SELECT ST_Envelope(ST_Collect(geom))
|
||||
FROM nodes JOIN way_nodes ON way_nodes.node_id = nodes.id
|
||||
WHERE way_nodes.way_id = ways.id
|
||||
);*/
|
||||
|
||||
-- Update the linestring column of the way table.
|
||||
/*SELECT AddGeometryColumn('ways', 'linestring', 4326, 'GEOMETRY', 2);
|
||||
UPDATE ways w SET linestring = (
|
||||
SELECT ST_MakeLine(c.geom) AS way_line FROM (
|
||||
SELECT n.geom AS geom
|
||||
FROM nodes n INNER JOIN way_nodes wn ON n.id = wn.node_id
|
||||
WHERE (wn.way_id = w.id) ORDER BY wn.sequence_id
|
||||
) c
|
||||
);*/
|
||||
|
||||
-- Index the way bounding box column. If you don't have one of these columns, comment out the index
|
||||
CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);
|
||||
CREATE INDEX idx_ways_linestring ON ways USING gist (linestring);
|
||||
|
||||
ALTER TABLE ONLY ways CLUSTER ON idx_ways_bbox;
|
||||
ALTER TABLE ONLY ways CLUSTER ON idx_ways_linestring;
|
||||
|
||||
-- Optional: CLUSTER imported tables. CLUSTER takes a significant amount of time to run and a
|
||||
-- significant amount of free disk space but speeds up some queries.
|
||||
|
||||
--CLUSTER nodes;
|
||||
--CLUSTER ways;
|
||||
|
||||
-- It is not necessary to CLUSTER way_nodes or relation_members after the initial load but you might want to do so later on
|
||||
|
||||
-- Perform database maintenance due to large database changes.
|
||||
ANALYZE;
|
170
script/pgsnapshot_schema_0.6.sql
Normal file
170
script/pgsnapshot_schema_0.6.sql
Normal file
@@ -0,0 +1,170 @@
|
||||
-- Database creation script for the snapshot PostgreSQL schema.
|
||||
|
||||
-- Drop all tables if they exist.
|
||||
DROP TABLE IF EXISTS actions;
|
||||
DROP TABLE IF EXISTS users;
|
||||
DROP TABLE IF EXISTS nodes;
|
||||
DROP TABLE IF EXISTS ways;
|
||||
DROP TABLE IF EXISTS way_nodes;
|
||||
DROP TABLE IF EXISTS relations;
|
||||
DROP TABLE IF EXISTS relation_members;
|
||||
DROP TABLE IF EXISTS schema_info;
|
||||
|
||||
-- Drop all stored procedures if they exist.
|
||||
DROP FUNCTION IF EXISTS osmosisUpdate();
|
||||
|
||||
|
||||
-- Create a table which will contain a single row defining the current schema version.
|
||||
CREATE TABLE schema_info (
|
||||
version integer NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for users.
|
||||
CREATE TABLE users (
|
||||
id int NOT NULL,
|
||||
name text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for nodes.
|
||||
CREATE TABLE nodes (
|
||||
id bigint NOT NULL,
|
||||
version int NOT NULL,
|
||||
user_id int NOT NULL,
|
||||
tstamp timestamp without time zone NOT NULL,
|
||||
changeset_id bigint NOT NULL,
|
||||
tags hstore
|
||||
);
|
||||
-- Add a postgis point column holding the location of the node.
|
||||
SELECT AddGeometryColumn('nodes', 'geom', 4326, 'POINT', 2);
|
||||
|
||||
|
||||
-- Create a table for ways.
|
||||
CREATE TABLE ways (
|
||||
id bigint NOT NULL,
|
||||
version int NOT NULL,
|
||||
user_id int NOT NULL,
|
||||
tstamp timestamp without time zone NOT NULL,
|
||||
changeset_id bigint NOT NULL,
|
||||
tags hstore,
|
||||
nodes bigint[]
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for representing way to node relationships.
|
||||
CREATE TABLE way_nodes (
|
||||
way_id bigint NOT NULL,
|
||||
node_id bigint NOT NULL,
|
||||
sequence_id int NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Create a table for relations.
|
||||
CREATE TABLE relations (
|
||||
id bigint NOT NULL,
|
||||
version int NOT NULL,
|
||||
user_id int NOT NULL,
|
||||
tstamp timestamp without time zone NOT NULL,
|
||||
changeset_id bigint NOT NULL,
|
||||
tags hstore
|
||||
);
|
||||
|
||||
-- Create a table for representing relation member relationships.
|
||||
CREATE TABLE relation_members (
|
||||
relation_id bigint NOT NULL,
|
||||
member_id bigint NOT NULL,
|
||||
member_type character(1) NOT NULL,
|
||||
member_role text NOT NULL,
|
||||
sequence_id int NOT NULL
|
||||
);
|
||||
|
||||
|
||||
-- Configure the schema version.
|
||||
INSERT INTO schema_info (version) VALUES (6);
|
||||
|
||||
|
||||
-- Add primary keys to tables.
|
||||
ALTER TABLE ONLY schema_info ADD CONSTRAINT pk_schema_info PRIMARY KEY (version);
|
||||
|
||||
ALTER TABLE ONLY users ADD CONSTRAINT pk_users PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id);
|
||||
|
||||
ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id);
|
||||
|
||||
ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id);
|
||||
|
||||
|
||||
-- Add indexes to tables.
|
||||
CREATE INDEX idx_nodes_geom ON nodes USING gist (geom);
|
||||
|
||||
CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id);
|
||||
|
||||
CREATE INDEX idx_relation_members_member_id_and_type ON relation_members USING btree (member_id, member_type);
|
||||
|
||||
|
||||
-- Set to cluster nodes by geographical location.
|
||||
ALTER TABLE ONLY nodes CLUSTER ON idx_nodes_geom;
|
||||
|
||||
-- Set to cluster the tables showing relationship by parent ID and sequence
|
||||
ALTER TABLE ONLY way_nodes CLUSTER ON pk_way_nodes;
|
||||
ALTER TABLE ONLY relation_members CLUSTER ON pk_relation_members;
|
||||
|
||||
-- There are no sensible CLUSTER orders for users or relations.
|
||||
-- Depending on geometry columns different clustings of ways may be desired.
|
||||
|
||||
-- Create the function that provides "unnest" functionality while remaining compatible with 8.3.
|
||||
CREATE OR REPLACE FUNCTION unnest_bbox_way_nodes() RETURNS void AS $$
|
||||
DECLARE
|
||||
previousId ways.id%TYPE;
|
||||
currentId ways.id%TYPE;
|
||||
result bigint[];
|
||||
wayNodeRow way_nodes%ROWTYPE;
|
||||
wayNodes ways.nodes%TYPE;
|
||||
BEGIN
|
||||
FOR wayNodes IN SELECT bw.nodes FROM bbox_ways bw LOOP
|
||||
FOR i IN 1 .. array_upper(wayNodes, 1) LOOP
|
||||
INSERT INTO bbox_way_nodes (id) VALUES (wayNodes[i]);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
-- Create customisable hook function that is called within the replication update transaction.
|
||||
CREATE FUNCTION osmosisUpdate() RETURNS void AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Manually set statistics for the way_nodes and relation_members table
|
||||
-- Postgres gets horrible counts of distinct values by sampling random pages
|
||||
-- and can be off by an 1-2 orders of magnitude
|
||||
|
||||
-- Size of the ways table / size of the way_nodes table
|
||||
ALTER TABLE way_nodes ALTER COLUMN way_id SET (n_distinct = -0.08);
|
||||
|
||||
-- Size of the nodes table / size of the way_nodes table * 0.998
|
||||
-- 0.998 is a factor for nodes not in ways
|
||||
ALTER TABLE way_nodes ALTER COLUMN node_id SET (n_distinct = -0.83);
|
||||
|
||||
-- API allows a maximum of 2000 nodes/way. Unlikely to impact query plans.
|
||||
ALTER TABLE way_nodes ALTER COLUMN sequence_id SET (n_distinct = 2000);
|
||||
|
||||
-- Size of the relations table / size of the relation_members table
|
||||
ALTER TABLE relation_members ALTER COLUMN relation_id SET (n_distinct = -0.09);
|
||||
|
||||
-- Based on June 2013 data
|
||||
ALTER TABLE relation_members ALTER COLUMN member_id SET (n_distinct = -0.62);
|
||||
|
||||
-- Based on June 2013 data. Unlikely to impact query plans.
|
||||
ALTER TABLE relation_members ALTER COLUMN member_role SET (n_distinct = 6500);
|
||||
|
||||
-- Based on June 2013 data. Unlikely to impact query plans.
|
||||
ALTER TABLE relation_members ALTER COLUMN sequence_id SET (n_distinct = 10000);
|
15
script/pgsnapshot_schema_0.6_action.sql
Normal file
15
script/pgsnapshot_schema_0.6_action.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
-- Add an action table for the purpose of capturing all actions applied to a database.
|
||||
-- The table is populated during application of a changeset, then osmosisUpdate is called,
|
||||
-- then the table is cleared all within a single database transaction.
|
||||
-- The contents of this table can be used to update derivative tables by customising the
|
||||
-- osmosisUpdate stored procedure.
|
||||
|
||||
-- Create a table for actions.
|
||||
CREATE TABLE actions (
|
||||
data_type character(1) NOT NULL,
|
||||
action character(1) NOT NULL,
|
||||
id bigint NOT NULL
|
||||
);
|
||||
|
||||
-- Add primary key.
|
||||
ALTER TABLE ONLY actions ADD CONSTRAINT pk_actions PRIMARY KEY (data_type, id);
|
21
script/pgsnapshot_schema_0.6_bbox.sql
Normal file
21
script/pgsnapshot_schema_0.6_bbox.sql
Normal file
@@ -0,0 +1,21 @@
|
||||
-- Add a postgis GEOMETRY column to the way table for the purpose of indexing the location of the way.
|
||||
-- This will contain a bounding box surrounding the extremities of the way.
|
||||
SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2);
|
||||
|
||||
-- Add an index to the bbox column.
|
||||
CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);
|
||||
|
||||
-- Cluster table by geographical location.
|
||||
CLUSTER ways USING idx_ways_bbox;
|
||||
|
||||
-- Create an aggregate function that always returns the first non-NULL item. This is required for bbox queries.
|
||||
CREATE OR REPLACE FUNCTION first_agg (anyelement, anyelement)
|
||||
RETURNS anyelement AS $$
|
||||
SELECT CASE WHEN $1 IS NULL THEN $2 ELSE $1 END;
|
||||
$$ LANGUAGE SQL STABLE;
|
||||
|
||||
CREATE AGGREGATE first (
|
||||
sfunc = first_agg,
|
||||
basetype = anyelement,
|
||||
stype = anyelement
|
||||
);
|
8
script/pgsnapshot_schema_0.6_linestring.sql
Normal file
8
script/pgsnapshot_schema_0.6_linestring.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
-- Add a postgis GEOMETRY column to the way table for the purpose of storing the full linestring of the way.
|
||||
SELECT AddGeometryColumn('ways', 'linestring', 4326, 'GEOMETRY', 2);
|
||||
|
||||
-- Add an index to the bbox column.
|
||||
CREATE INDEX idx_ways_linestring ON ways USING gist (linestring);
|
||||
|
||||
-- Cluster table by geographical location.
|
||||
CLUSTER ways USING idx_ways_linestring;
|
5
script/pgsnapshot_schema_0.6_upgrade_4-5.sql
Normal file
5
script/pgsnapshot_schema_0.6_upgrade_4-5.sql
Normal file
@@ -0,0 +1,5 @@
|
||||
-- Add the relation members primary key.
|
||||
ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id);
|
||||
|
||||
-- Upgrade the schema version.
|
||||
UPDATE schema_info SET version = 5;
|
238
script/pgsnapshot_schema_0.6_upgrade_5-6.sql
Normal file
238
script/pgsnapshot_schema_0.6_upgrade_5-6.sql
Normal file
@@ -0,0 +1,238 @@
|
||||
-- Database script for the simple PostgreSQL schema. This script moves all tags into hstore columns.
|
||||
|
||||
-- Create functions for building hstore data.
|
||||
CREATE OR REPLACE FUNCTION build_node_tags() RETURNS void AS $$
|
||||
DECLARE
|
||||
previousId nodes.id%TYPE;
|
||||
currentId nodes.id%TYPE;
|
||||
result hstore;
|
||||
tagRow node_tags%ROWTYPE;
|
||||
BEGIN
|
||||
SET enable_seqscan = false;
|
||||
SET enable_mergejoin = false;
|
||||
SET enable_hashjoin = false;
|
||||
|
||||
FOR tagRow IN SELECT * FROM node_tags ORDER BY node_id LOOP
|
||||
currentId := tagRow.node_id;
|
||||
|
||||
IF currentId <> previousId THEN
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE nodes SET tags = result WHERE id = previousId;
|
||||
IF ((currentId / 100000) <> (previousId / 100000)) THEN
|
||||
RAISE INFO 'node id: %', previousId;
|
||||
END IF;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF result IS NULL THEN
|
||||
result := tagRow.k => tagRow.v;
|
||||
ELSE
|
||||
result := result || (tagRow.k => tagRow.v);
|
||||
END IF;
|
||||
|
||||
previousId := currentId;
|
||||
END LOOP;
|
||||
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE nodes SET tags = result WHERE id = previousId;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION build_way_tags() RETURNS void AS $$
|
||||
DECLARE
|
||||
previousId ways.id%TYPE;
|
||||
currentId ways.id%TYPE;
|
||||
result hstore;
|
||||
tagRow way_tags%ROWTYPE;
|
||||
BEGIN
|
||||
SET enable_seqscan = false;
|
||||
SET enable_mergejoin = false;
|
||||
SET enable_hashjoin = false;
|
||||
|
||||
FOR tagRow IN SELECT * FROM way_tags ORDER BY way_id LOOP
|
||||
currentId := tagRow.way_id;
|
||||
|
||||
IF currentId <> previousId THEN
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE ways SET tags = result WHERE id = previousId;
|
||||
IF ((currentId / 100000) <> (previousId / 100000)) THEN
|
||||
RAISE INFO 'way id: %', previousId;
|
||||
END IF;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF result IS NULL THEN
|
||||
result := tagRow.k => tagRow.v;
|
||||
ELSE
|
||||
result := result || (tagRow.k => tagRow.v);
|
||||
END IF;
|
||||
|
||||
previousId := currentId;
|
||||
END LOOP;
|
||||
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE ways SET tags = result WHERE id = previousId;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION build_relation_tags() RETURNS void AS $$
|
||||
DECLARE
|
||||
previousId relations.id%TYPE;
|
||||
currentId relations.id%TYPE;
|
||||
result hstore;
|
||||
tagRow relation_tags%ROWTYPE;
|
||||
BEGIN
|
||||
SET enable_seqscan = false;
|
||||
SET enable_mergejoin = false;
|
||||
SET enable_hashjoin = false;
|
||||
|
||||
FOR tagRow IN SELECT * FROM relation_tags ORDER BY relation_id LOOP
|
||||
currentId := tagRow.relation_id;
|
||||
|
||||
IF currentId <> previousId THEN
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE relations SET tags = result WHERE id = previousId;
|
||||
IF ((currentId / 100000) <> (previousId / 100000)) THEN
|
||||
RAISE INFO 'relation id: %', previousId;
|
||||
END IF;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF result IS NULL THEN
|
||||
result := tagRow.k => tagRow.v;
|
||||
ELSE
|
||||
result := result || (tagRow.k => tagRow.v);
|
||||
END IF;
|
||||
|
||||
previousId := currentId;
|
||||
END LOOP;
|
||||
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE relations SET tags = result WHERE id = previousId;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION build_way_nodes() RETURNS void AS $$
|
||||
DECLARE
|
||||
previousId ways.id%TYPE;
|
||||
currentId ways.id%TYPE;
|
||||
result bigint[];
|
||||
wayNodeRow way_nodes%ROWTYPE;
|
||||
BEGIN
|
||||
SET enable_seqscan = false;
|
||||
SET enable_mergejoin = false;
|
||||
SET enable_hashjoin = false;
|
||||
|
||||
FOR wayNodeRow IN SELECT * FROM way_nodes ORDER BY way_id, sequence_id LOOP
|
||||
currentId := wayNodeRow.way_id;
|
||||
|
||||
IF currentId <> previousId THEN
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE ways SET nodes = result WHERE id = previousId;
|
||||
IF ((currentId / 100000) <> (previousId / 100000)) THEN
|
||||
RAISE INFO 'way id: %', previousId;
|
||||
END IF;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF result IS NULL THEN
|
||||
result = ARRAY[wayNodeRow.node_id];
|
||||
ELSE
|
||||
result = array_append(result, wayNodeRow.node_id);
|
||||
END IF;
|
||||
|
||||
previousId := currentId;
|
||||
END LOOP;
|
||||
|
||||
IF previousId IS NOT NULL THEN
|
||||
IF result IS NOT NULL THEN
|
||||
UPDATE ways SET nodes = result WHERE id = previousId;
|
||||
result := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Add hstore columns to entity tables.
|
||||
ALTER TABLE nodes ADD COLUMN tags hstore;
|
||||
ALTER TABLE ways ADD COLUMN tags hstore;
|
||||
ALTER TABLE relations ADD COLUMN tags hstore;
|
||||
|
||||
-- Populate the hstore columns.
|
||||
SELECT build_node_tags();
|
||||
SELECT build_way_tags();
|
||||
SELECT build_relation_tags();
|
||||
|
||||
-- Remove the hstore functions.
|
||||
DROP FUNCTION build_node_tags();
|
||||
DROP FUNCTION build_way_tags();
|
||||
DROP FUNCTION build_relation_tags();
|
||||
|
||||
-- Drop the now redundant tag tables.
|
||||
DROP TABLE node_tags;
|
||||
DROP TABLE way_tags;
|
||||
DROP TABLE relation_tags;
|
||||
|
||||
-- Add an index allowing relation_members to be queried by member id and type.
|
||||
CREATE INDEX idx_relation_members_member_id_and_type ON relation_members USING btree (member_id, member_type);
|
||||
|
||||
-- Add the nodes column to the ways table.
|
||||
ALTER TABLE ways ADD COLUMN nodes bigint[];
|
||||
|
||||
-- Populate the new nodes column on the ways table.
|
||||
SELECT build_way_nodes();
|
||||
--UPDATE ways w SET nodes = ARRAY(SELECT wn.node_id FROM way_nodes wn WHERE w.id = wn.way_id ORDER BY sequence_id);
|
||||
|
||||
-- Remove the way nodes function.
|
||||
DROP FUNCTION build_way_nodes();
|
||||
|
||||
-- Organise data according to geographical location.
|
||||
CLUSTER nodes USING idx_nodes_geom;
|
||||
CLUSTER ways USING idx_ways_linestring;
|
||||
|
||||
-- Create the function that provides "unnest" functionality while remaining compatible with 8.3.
|
||||
CREATE OR REPLACE FUNCTION unnest_bbox_way_nodes() RETURNS void AS $$
|
||||
DECLARE
|
||||
previousId ways.id%TYPE;
|
||||
currentId ways.id%TYPE;
|
||||
result bigint[];
|
||||
wayNodeRow way_nodes%ROWTYPE;
|
||||
wayNodes ways.nodes%TYPE;
|
||||
BEGIN
|
||||
FOR wayNodes IN SELECT bw.nodes FROM bbox_ways bw LOOP
|
||||
FOR i IN 1 .. array_upper(wayNodes, 1) LOOP
|
||||
INSERT INTO bbox_way_nodes (id) VALUES (wayNodes[i]);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
-- Update the schema version.
|
||||
UPDATE schema_info SET version = 6;
|
||||
|
||||
VACUUM ANALYZE;
|
Reference in New Issue
Block a user