source: other-projects/tipple-android/osmosis/script/pgsimple_load_0.6.sql@ 26899

Last change on this file since 26899 was 26899, checked in by davidb, 11 years ago

Tipple reborn after Chris's Summer of Code 2013

File size: 2.9 KB
Line 
1-- Drop all primary keys and indexes to improve load speed.
2ALTER TABLE nodes DROP CONSTRAINT pk_nodes;
3ALTER TABLE ways DROP CONSTRAINT pk_ways;
4ALTER TABLE way_nodes DROP CONSTRAINT pk_way_nodes;
5ALTER TABLE relations DROP CONSTRAINT pk_relations;
6ALTER TABLE relation_members DROP CONSTRAINT pk_relation_members;
7DROP INDEX idx_node_tags_node_id;
8DROP INDEX idx_nodes_geom;
9DROP INDEX idx_way_tags_way_id;
10DROP INDEX idx_way_nodes_node_id;
11DROP INDEX idx_relation_tags_relation_id;
12DROP INDEX idx_ways_bbox;
13DROP INDEX idx_ways_linestring;
14
15-- Comment these out if the COPY files include bbox or linestring column values.
16SELECT DropGeometryColumn('ways', 'bbox');
17SELECT DropGeometryColumn('ways', 'linestring');
18
19-- Import the table data from the data files using the fast COPY method.
20\copy users FROM 'users.txt'
21\copy nodes FROM 'nodes.txt'
22\copy node_tags FROM 'node_tags.txt'
23\copy ways FROM 'ways.txt'
24\copy way_tags FROM 'way_tags.txt'
25\copy way_nodes FROM 'way_nodes.txt'
26\copy relations FROM 'relations.txt'
27\copy relation_tags FROM 'relation_tags.txt'
28\copy relation_members FROM 'relation_members.txt'
29
30-- Add the primary keys and indexes back again (except the way bbox index).
31ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id);
32ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id);
33ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id);
34ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id);
35ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id);
36CREATE INDEX idx_node_tags_node_id ON node_tags USING btree (node_id);
37CREATE INDEX idx_nodes_geom ON nodes USING gist (geom);
38CREATE INDEX idx_way_tags_way_id ON way_tags USING btree (way_id);
39CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id);
40CREATE INDEX idx_relation_tags_relation_id ON relation_tags USING btree (relation_id);
41
42-- Comment these out if the COPY files include bbox or linestring column values.
43SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2);
44SELECT AddGeometryColumn('ways', 'linestring', 4326, 'GEOMETRY', 2);
45
46-- Comment these out if the COPY files include bbox or linestring column values.
47-- Update the bbox column of the way table.
48UPDATE ways SET bbox = (
49 SELECT Envelope(Collect(geom))
50 FROM nodes JOIN way_nodes ON way_nodes.node_id = nodes.id
51 WHERE way_nodes.way_id = ways.id
52);
53-- Update the linestring column of the way table.
54UPDATE ways w SET linestring = (
55 SELECT ST_MakeLine(c.geom) AS way_line FROM (
56 SELECT n.geom AS geom
57 FROM nodes n INNER JOIN way_nodes wn ON n.id = wn.node_id
58 WHERE (wn.way_id = w.id) ORDER BY wn.sequence_id
59 ) c
60)
61
62-- Index the way bounding box column.
63CREATE INDEX idx_ways_bbox ON ways USING gist (bbox);
64CREATE INDEX idx_ways_linestring ON ways USING gist (linestring);
65
66-- Perform database maintenance due to large database changes.
67VACUUM ANALYZE;
Note: See TracBrowser for help on using the repository browser.