Skip to content

Commit

Permalink
Updated the pgsql simple tasks to use the new database schema which i…
Browse files Browse the repository at this point in the history
…s more similar to the one used in the central MySQL
  • Loading branch information
Jochen Topf committed Jun 29, 2008
1 parent 83cf69a commit 330bb5c
Show file tree
Hide file tree
Showing 37 changed files with 299 additions and 279 deletions.
1 change: 1 addition & 0 deletions changes.txt
Expand Up @@ -3,6 +3,7 @@ Fixed the --write-pgsql-simple-dump task to properly escape '\' characters.
Updated the pgsql simple tasks to use an SRID of 4326.
Updated build script to include a tar file distribution preserving launch script execute permissions.
Enhanced the Entity class to allow dates to be represented as strings to avoid parsing overhead. Updated xml tasks to utilise this feature.
Updated the pgsql simple tasks to use the new database schema which is more similar to the one used in the central MySQL

0.28
Added a maximum file download count feature to the change downloader to limit processing overhead when synchronising long time intervals.
Expand Down
84 changes: 50 additions & 34 deletions script/pgsql_simple_load.sql
@@ -1,46 +1,62 @@
-- Drop all primary keys and indexes to improve load speed.
ALTER TABLE node DROP CONSTRAINT pk_node;
ALTER TABLE way DROP CONSTRAINT pk_way;
ALTER TABLE way_node DROP CONSTRAINT pk_way_node;
ALTER TABLE relation DROP CONSTRAINT pk_relation;
DROP INDEX idx_node_tag_node_id;
DROP INDEX idx_node_location;
DROP INDEX idx_way_tag_way_id;
DROP INDEX idx_way_node_node_id;
DROP INDEX idx_relation_tag_relation_id;
DROP INDEX idx_way_bbox;
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;
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;

SELECT DropGeometryColumn('ways', 'bbox');

-- Import the table data from the data files using the fast COPY method.
COPY node FROM E'C:\\tmp\\pgimport\\node.txt';
COPY node_tag FROM E'C:\\tmp\\pgimport\\node_tag.txt';
COPY way FROM E'C:\\tmp\\pgimport\\way.txt';
COPY way_tag FROM E'C:\\tmp\\pgimport\\way_tag.txt';
COPY way_node FROM E'C:\\tmp\\pgimport\\way_node.txt';
COPY relation FROM E'C:\\tmp\\pgimport\\relation.txt';
COPY relation_tag FROM E'C:\\tmp\\pgimport\\relation_tag.txt';
COPY relation_member FROM E'C:\\tmp\\pgimport\\relation_member.txt';
-- COPY nodes FROM E'C:\\tmp\\pgimport\\nodes.txt';
-- COPY node_tags FROM E'C:\\tmp\\pgimport\\node_tags.txt';
-- COPY ways FROM E'C:\\tmp\\pgimport\\ways.txt';
-- COPY way_tags FROM E'C:\\tmp\\pgimport\\way_tags.txt';
-- COPY way_nodes FROM E'C:\\tmp\\pgimport\\way_nodes.txt';
-- COPY relations FROM E'C:\\tmp\\pgimport\\relations.txt';
-- COPY relation_tags FROM E'C:\\tmp\\pgimport\\relation_tags.txt';
-- COPY relation_members FROM E'C:\\tmp\\pgimport\\relation_members.txt';

-- or do it this way
\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 node ADD CONSTRAINT pk_node PRIMARY KEY (id);
ALTER TABLE ONLY way ADD CONSTRAINT pk_way PRIMARY KEY (id);
ALTER TABLE ONLY way_node ADD CONSTRAINT pk_way_node PRIMARY KEY (way_id, sequence_id);
ALTER TABLE ONLY relation ADD CONSTRAINT pk_relation PRIMARY KEY (id);
CREATE INDEX idx_node_tag_node_id ON node_tag USING btree (node_id);
CREATE INDEX idx_node_location ON node USING gist (coordinate);
CREATE INDEX idx_way_tag_way_id ON way_tag USING btree (way_id);
CREATE INDEX idx_way_node_node_id ON way_node USING btree (node_id);
CREATE INDEX idx_relation_tag_relation_id ON relation_tag USING btree (relation_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);
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);

-- Add a postgis bounding box column used for 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);

-- Update the bbox column of the way table.
UPDATE way SET bbox = (
SELECT Envelope(Collect(coordinate))
FROM node JOIN way_node ON way_node.node_id = node.id
WHERE way_node.way_id = way.id
UPDATE ways SET bbox = (
SELECT Envelope(Collect(geom))
FROM nodes JOIN way_nodes ON way_nodes.node_id = nodes.id
WHERE way_nodes.way_id = ways.id
);

-- Index the way bounding box column.
CREATE INDEX idx_way_bbox ON way USING gist (bbox);
CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);

-- Perform database maintenance due to large database changes.
VACUUM;
ANALYZE;
VACUUM ANALYZE;

68 changes: 34 additions & 34 deletions script/pgsql_simple_schema.sql
@@ -1,14 +1,14 @@
-- Database creation script for the simple PostgreSQL schema.

-- Drop all tables if they exist.
DROP TABLE IF EXISTS node;
DROP TABLE IF EXISTS node_tag;
DROP TABLE IF EXISTS way;
DROP TABLE IF EXISTS way_node;
DROP TABLE IF EXISTS way_tag;
DROP TABLE IF EXISTS relation;
DROP TABLE IF EXISTS relation_member;
DROP TABLE IF EXISTS relation_tag;
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;


Expand All @@ -19,58 +19,58 @@ CREATE TABLE schema_info (


-- Create a table for nodes.
CREATE TABLE node (
CREATE TABLE nodes (
id bigint NOT NULL,
user_name text NOT NULL,
tstamp timestamp without time zone NOT NULL
);
-- Add a postgis point column holding the location of the node.
SELECT AddGeometryColumn('node', 'coordinate', -1, 'POINT', 2);
SELECT AddGeometryColumn('nodes', 'geom', 4326, 'POINT', 2);

-- Create a table for node tags.
CREATE TABLE node_tag (
CREATE TABLE node_tags (
node_id bigint NOT NULL,
name text NOT NULL,
value text NOT NULL
k text NOT NULL,
v text NOT NULL
);


-- Create a table for ways.
CREATE TABLE way (
CREATE TABLE ways (
id bigint NOT NULL,
user_name text NOT NULL,
tstamp timestamp without time zone NOT NULL
);
-- Add a postgis bounding box column used for indexing the location of the way.
-- This will contain a bounding box surrounding the extremities of the way.
SELECT AddGeometryColumn('way', 'bbox', -1, 'GEOMETRY', 2);
SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2);


-- Create a table for representing way to node relationships.
CREATE TABLE way_node (
CREATE TABLE way_nodes (
way_id bigint NOT NULL,
node_id bigint NOT NULL,
sequence_id smallint NOT NULL
);


-- Create a table for way tags.
CREATE TABLE way_tag (
CREATE TABLE way_tags (
way_id bigint NOT NULL,
name text NOT NULL,
value text
k text NOT NULL,
v text
);


-- Create a table for relations.
CREATE TABLE relation (
CREATE TABLE relations (
id bigint NOT NULL,
user_name text NOT NULL,
tstamp timestamp without time zone NOT NULL
);

-- Create a table for representing relation member relationships.
CREATE TABLE relation_member (
CREATE TABLE relation_members (
relation_id bigint NOT NULL,
member_id bigint NOT NULL,
member_role text NOT NULL,
Expand All @@ -79,10 +79,10 @@ CREATE TABLE relation_member (


-- Create a table for relation tags.
CREATE TABLE relation_tag (
CREATE TABLE relation_tags (
relation_id bigint NOT NULL,
name text NOT NULL,
value text NOT NULL
k text NOT NULL,
v text NOT NULL
);


Expand All @@ -95,27 +95,27 @@ INSERT INTO schema_info (version) VALUES (1);
ALTER TABLE ONLY schema_info ADD CONSTRAINT pk_schema_info PRIMARY KEY (version);


ALTER TABLE ONLY node ADD CONSTRAINT pk_node PRIMARY KEY (id);
ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id);


ALTER TABLE ONLY way ADD CONSTRAINT pk_way PRIMARY KEY (id);
ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id);


ALTER TABLE ONLY way_node ADD CONSTRAINT pk_way_node PRIMARY KEY (way_id, sequence_id);
ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id);


ALTER TABLE ONLY relation ADD CONSTRAINT pk_relation PRIMARY KEY (id);
ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id);


-- Add indexes to tables.

CREATE INDEX idx_node_tag_node_id ON node_tag USING btree (node_id);
CREATE INDEX idx_node_location ON node USING gist (coordinate);
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_tag_way_id ON way_tag USING btree (way_id);
CREATE INDEX idx_way_bbox ON way USING gist (bbox);
CREATE INDEX idx_way_node_node_id ON way_node USING btree (node_id);
CREATE INDEX idx_way_tags_way_id ON way_tags USING btree (way_id);
CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);
CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id);


CREATE INDEX idx_relation_tag_relation_id ON relation_tag USING btree (relation_id);
CREATE INDEX idx_relation_tags_relation_id ON relation_tags USING btree (relation_id);
Expand Up @@ -30,14 +30,14 @@
*/
public class PostgreSqlDatasetDumpWriter implements Sink, EntityProcessor {

private static final String NODE_SUFFIX = "node.txt";
private static final String NODE_TAG_SUFFIX = "node_tag.txt";
private static final String WAY_SUFFIX = "way.txt";
private static final String WAY_TAG_SUFFIX = "way_tag.txt";
private static final String WAY_NODE_SUFFIX = "way_node.txt";
private static final String RELATION_SUFFIX = "relation.txt";
private static final String RELATION_TAG_SUFFIX = "relation_tag.txt";
private static final String RELATION_MEMBER_SUFFIX = "relation_member.txt";
private static final String NODE_SUFFIX = "nodes.txt";
private static final String NODE_TAG_SUFFIX = "node_tags.txt";
private static final String WAY_SUFFIX = "ways.txt";
private static final String WAY_TAG_SUFFIX = "way_tags.txt";
private static final String WAY_NODE_SUFFIX = "way_nodes.txt";
private static final String RELATION_SUFFIX = "relations.txt";
private static final String RELATION_TAG_SUFFIX = "relation_tags.txt";
private static final String RELATION_MEMBER_SUFFIX = "relation_members.txt";


private CompletableContainer writerContainer;
Expand Down
Expand Up @@ -18,7 +18,7 @@ public class PostgreSqlDatasetTruncator implements RunnableTask {

// These SQL statements will be invoked to truncate each table.
private static final String[] SQL_STATEMENTS = {
"TRUNCATE node, node_tag, way, way_tag, way_node, relation, relation_tag, relation_member"
"TRUNCATE nodes, node_tags, ways, way_tags, way_nodes, relations, relation_tags, relation_members"
};


Expand Down
54 changes: 27 additions & 27 deletions src/com/bretth/osmosis/core/pdb/v0_5/PostgreSqlWriter.java
Expand Up @@ -48,56 +48,56 @@ public class PostgreSqlWriter implements Sink, EntityProcessor {


private static final String PRE_LOAD_SQL[] = {
"ALTER TABLE node DROP CONSTRAINT pk_node",
"ALTER TABLE way DROP CONSTRAINT pk_way",
"ALTER TABLE way_node DROP CONSTRAINT pk_way_node",
"ALTER TABLE relation DROP CONSTRAINT pk_relation",
"DROP INDEX idx_node_tag_node_id",
"DROP INDEX idx_node_location",
"DROP INDEX idx_way_tag_way_id",
"DROP INDEX idx_relation_tag_relation_id",
"DROP INDEX idx_way_bbox"
"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",
"DROP INDEX idx_node_tags_node_id",
"DROP INDEX idx_nodes_geom",
"DROP INDEX idx_way_tags_way_id",
"DROP INDEX idx_relation_tags_relation_id",
"DROP INDEX idx_ways_bbox"
};

private static final String POST_LOAD_SQL[] = {
"ALTER TABLE ONLY node ADD CONSTRAINT pk_node PRIMARY KEY (id)",
"ALTER TABLE ONLY way ADD CONSTRAINT pk_way PRIMARY KEY (id)",
"ALTER TABLE ONLY way_node ADD CONSTRAINT pk_way_node PRIMARY KEY (way_id, sequence_id)",
"ALTER TABLE ONLY relation ADD CONSTRAINT pk_relation PRIMARY KEY (id)",
"CREATE INDEX idx_node_tag_node_id ON node_tag USING btree (node_id)",
"CREATE INDEX idx_node_location ON node USING gist (coordinate)",
"CREATE INDEX idx_way_tag_way_id ON way_tag USING btree (way_id)",
"CREATE INDEX idx_relation_tag_relation_id ON relation_tag USING btree (relation_id)",
"UPDATE way SET bbox = (SELECT Envelope(Collect(coordinate)) FROM node JOIN way_node ON way_node.node_id = node.id WHERE way_node.way_id = way.id)",
"CREATE INDEX idx_way_bbox ON way USING gist (bbox)"
"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)",
"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_relation_tags_relation_id ON relation_tags USING btree (relation_id)",
"UPDATE ways SET bbox = (SELECT Envelope(Collect(geom)) FROM nodes JOIN way_nodes ON way_nodes.node_id = nodes.id WHERE way_nodes.way_id = ways.id)",
"CREATE INDEX idx_ways_bbox ON ways USING gist (bbox)"
};


// These SQL strings are the prefix to statements that will be built based
// on how many rows of data are to be inserted at a time.
private static final String INSERT_SQL_NODE =
"INSERT INTO node(id, tstamp, user_name, coordinate)";
"INSERT INTO nodes(id, tstamp, user_name, geom)";
private static final int INSERT_PRM_COUNT_NODE = 4;
private static final String INSERT_SQL_NODE_TAG =
"INSERT INTO node_tag(node_id, name, value)";
"INSERT INTO node_tags(node_id, k, v)";
private static final int INSERT_PRM_COUNT_NODE_TAG = 3;
private static final String INSERT_SQL_WAY =
"INSERT INTO way(id, tstamp, user_name)";
"INSERT INTO ways(id, tstamp, user_name)";
private static final int INSERT_PRM_COUNT_WAY = 3;
private static final String INSERT_SQL_WAY_TAG =
"INSERT INTO way_tag(way_id, name, value)";
"INSERT INTO way_tags(way_id, k, v)";
private static final int INSERT_PRM_COUNT_WAY_TAG = 3;
private static final String INSERT_SQL_WAY_NODE =
"INSERT INTO way_node(way_id, node_id, sequence_id)";
"INSERT INTO way_nodes(way_id, node_id, sequence_id)";
private static final int INSERT_PRM_COUNT_WAY_NODE = 3;
private static final String INSERT_SQL_RELATION =
"INSERT INTO relation(id, tstamp, user_name)";
"INSERT INTO relations(id, tstamp, user_name)";
private static final int INSERT_PRM_COUNT_RELATION = 3;
private static final String INSERT_SQL_RELATION_TAG =
"INSERT INTO relation_tag(relation_id, name, value)";
"INSERT INTO relation_tags(relation_id, k, v)";
private static final int INSERT_PRM_COUNT_RELATION_TAG = 3;
private static final String INSERT_SQL_RELATION_MEMBER =
"INSERT INTO relation_member(relation_id, member_id, member_type, member_role)";
"INSERT INTO relation_members(relation_id, member_id, member_type, member_role)";
private static final int INSERT_PRM_COUNT_RELATION_MEMBER = 4;

// These constants define how many rows of each data type will be inserted
Expand Down

0 comments on commit 330bb5c

Please sign in to comment.