Skip to content

Commit

Permalink
imposm3 merge complete
Browse files Browse the repository at this point in the history
  • Loading branch information
britiger committed Nov 13, 2017
1 parent 85d033d commit 4e564a7
Show file tree
Hide file tree
Showing 9 changed files with 120 additions and 162 deletions.
2 changes: 1 addition & 1 deletion initial_import.sh
Original file line number Diff line number Diff line change
Expand Up @@ -61,7 +61,7 @@ psql -f sql/planetCreateUpdateTables.sql > /dev/null
# create trigger for update tables
echo_time "Creating update triggers ..."
psql -f sql/planetCreateUpdateTriggers.sql > /dev/null
exit

# create functions
echo_time "Creating functions ..."
psql -f sql/createFunctions.sql > /dev/null
Expand Down
41 changes: 37 additions & 4 deletions mapping.json
Original file line number Diff line number Diff line change
Expand Up @@ -47,6 +47,13 @@
"suburb",
"locality"
]
},
"filter": {
"require": {
"name": [
"__any__"
]
}
}
},
"places_poly": {
Expand Down Expand Up @@ -75,7 +82,18 @@
"type": "integer",
"name": "population",
"key": "population"
},
{
"type": "string",
"name": "boundary",
"key": "boundary"
},
{
"type": "integer",
"name": "admin_level",
"key": "admin_level"
}

],
"type": "polygon",
"mapping": {
Expand All @@ -91,6 +109,13 @@
"suburb",
"locality"
]
},
"filter": {
"require": {
"name": [
"__any__"
]
}
}
},
"admin": {
Expand All @@ -112,12 +137,12 @@
},
{
"type": "string",
"name": "ISO3166-2",
"key": "ISO3166-2"
"name": "ISO3166-1",
"key": "ISO3166-1"
},
{
"type": "mapping_value",
"name": "type",
"name": "boundary",
"key": null
},
{
Expand All @@ -136,6 +161,9 @@
"require": {
"admin_level": [
"__any__"
],
"name": [
"__any__"
]
}
}
Expand Down Expand Up @@ -186,13 +214,18 @@
},
{
"type": "mapping_value",
"name": "type",
"name": "highway",
"key": null
},
{
"type": "string",
"name": "name",
"key": "name"
},
{
"type": "string",
"name": "addr:suburb",
"key": "addr:suburb"
}
],
"type": "linestring",
Expand Down
2 changes: 1 addition & 1 deletion osmupdate.sh
Original file line number Diff line number Diff line change
Expand Up @@ -121,7 +121,7 @@ then
# Save data of updates for polygon for next full update
psql -f sql/planetPolyMoveForFullUpdate.sql > /dev/null
fi
exit

# Complete Update table data in schema import
echo_time "Delete old elements ..."
psql -f sql/importDeleteOldEntries.sql > /dev/null
Expand Down
15 changes: 6 additions & 9 deletions sql/copyTables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,30 +9,28 @@ INSERT INTO import.osm_admin
SELECT osm_id, name, admin_level, "ISO3166-1", ST_Union(geometry) AS geometry
FROM osm_admin
WHERE ((admin_level = 2 AND "ISO3166-1" IS NOT NULL) OR admin_level>2)
AND osm_id IN (SELECT osm_id FROM update_polygon WHERE update_type!='D' AND osm_id < 0)
AND osm_id IN (SELECT osm_id FROM update_admin WHERE update_type!='D')
GROUP BY osm_id, name, admin_level, "ISO3166-1";

-- osm_postcode
INSERT INTO import.osm_postcode
SELECT osm_id, postal_code, ST_Union(geometry) AS geometry
FROM osm_postcode
WHERE osm_id IN (SELECT osm_id FROM update_polygon WHERE update_type!='D')
WHERE osm_id IN (SELECT osm_id FROM update_postcodes WHERE update_type!='D')
GROUP BY osm_id, postal_code;

-- osm_places
INSERT INTO import.osm_places
SELECT osm_id, class, name, type,
CASE WHEN population~E'^\\d+$' THEN population::bigint ELSE NULL::bigint END AS population,
ST_Union(geometry) AS geometry
SELECT osm_id, class, name, type, population, ST_Union(geometry) AS geometry
FROM osm_places
WHERE osm_id IN (SELECT osm_id FROM update_polygon_point WHERE update_type!='D')
WHERE osm_id IN (SELECT osm_id FROM update_places WHERE update_type!='D')
GROUP BY osm_id, class, name, type, population;

-- osm_roads
INSERT INTO import.osm_roads
SELECT osm_id, name, highway, "addr:suburb", geometry
FROM osm_roads
WHERE osm_id IN (SELECT osm_id FROM update_polygon_line WHERE update_type!='D');
WHERE osm_id IN (SELECT osm_id FROM update_roads WHERE update_type!='D');
UPDATE import.osm_roads SET geometry=ST_ExteriorRing(geometry) WHERE ST_geometrytype(geometry) = 'ST_Polygon';

-- osm_addresses
Expand All @@ -42,8 +40,7 @@ SELECT osm_id, class,
NULL::bigint AS "source:addr:country", NULL::bigint AS "source:addr:city", NULL::bigint AS "source:addr:postcode", NULL::bigint AS "source:addr:suburb", NULL::bigint AS "source:addr:place", NULL::bigint AS "source:addr:hamlet", NULL::bigint AS "source:addr:street",
ST_Union(geometry) AS geometry
FROM osm_addresses
WHERE osm_id IN (SELECT osm_id FROM update_polygon_point WHERE update_type!='D')
WHERE osm_id IN (SELECT osm_id FROM update_addresses WHERE update_type!='D')
GROUP BY osm_id, class,
"addr:country", "addr:city", "addr:postcode", "addr:street", "addr:housename", "addr:housenumber", "addr:suburb", "addr:place", "addr:hamlet",
"source:addr:country", "source:addr:city", "source:addr:postcode", "source:addr:suburb", "source:addr:place", "source:addr:hamlet", "source:addr:street";

91 changes: 6 additions & 85 deletions sql/createFunctions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,93 +4,14 @@ SET client_min_messages TO WARNING;
-- create functions for analyse relations

-- returns the value for the given key or NULL
CREATE OR REPLACE FUNCTION getValueOf(text, text[])
CREATE OR REPLACE FUNCTION getAssoStreet(bigint)
RETURNS text AS
$BODY$
DECLARE

BEGIN
IF array_upper($2,1)<2 THEN
Return NULL;
END IF;
FOR i IN 1..(array_upper($2,1)) LOOP

IF ($2[i]=$1) THEN
Return $2[i+1];
END IF;
i:=i+1;

END LOOP;
RETURN NULL;
END;
$BODY$
IMMUTABLE
PARALLEL SAFE
LANGUAGE plpgsql;

-- returns all elements of a specific role and type (role, type(way, polygon, point), member)
CREATE OR REPLACE FUNCTION getMembersRoleType(text, text, text[])
RETURNS bigint[] AS
$BODY$
DECLARE
result bigint[];
BEGIN
IF array_upper($3,1)<2 THEN
Return NULL;
END IF;
FOR i IN 1..(array_upper($3,1)) LOOP

IF ($3[i+1]=$1) THEN
IF ((substring($3[i] for 1)='n' AND $2='point') OR
(substring($3[i] for 1)='w' AND ($2='polygon' OR $2='way'))) THEN
result = array_append(result, substring($3[i] from 2)::bigint);
ELSIF (substring($3[i] for 1)='r' AND $2='polygon') THEN
result = array_append(result, substring($3[i] from 2)::bigint*-1);
END IF;
END IF;
i:=i+1;

END LOOP;
IF array_upper(result,1)<1 THEN
RETURN NULL;
ELSE
RETURN result;
END IF;
END;
$BODY$
'SELECT road.name
FROM imposm_asso_street asso INNER JOIN imposm_roads road ON asso.role=''street'' AND asso.osm_id=$1 AND asso.member_osm_id=road.osm_id
LIMIT 1;'
IMMUTABLE
PARALLEL SAFE
LANGUAGE plpgsql;

-- returns first element of a specific role and type (role, type(way, polygon, point), member)
CREATE OR REPLACE FUNCTION getMemberRoleType(text, text, text[])
RETURNS bigint AS
$BODY$
DECLARE

BEGIN
IF array_upper($3,1)<2 THEN
Return NULL;
END IF;
FOR i IN 1..(array_upper($3,1)) LOOP

IF ($3[i+1]=$1) THEN
IF ((substring($3[i] for 1)='n' AND $2='point') OR
(substring($3[i] for 1)='w' AND ($2='polygon' OR $2='way'))) THEN
RETURN substring($3[i] from 2)::bigint;
ELSIF (substring($3[i] for 1)='r' AND $2='polygon') THEN
RETURN substring($3[i] from 2)::bigint*-1;
END IF;
END IF;
i:=i+1;

END LOOP;
RETURN NULL;
END;
$BODY$
IMMUTABLE
PARALLEL SAFE
LANGUAGE plpgsql;
LANGUAGE SQL
RETURNS NULL ON NULL INPUT;

-- function for rating housenumbers for sorting
CREATE OR REPLACE FUNCTION sort_housenumber(housenumber text)
Expand Down
13 changes: 7 additions & 6 deletions sql/importApplyAssociatedStreet.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,11 +3,11 @@ SET client_min_messages TO WARNING;

-- create View to fill street and filter useless tupels
CREATE MATERIALIZED VIEW IF NOT EXISTS osm_associated_with_street AS
SELECT osm_id,
CASE WHEN name IS NULL THEN (SELECT name FROM osm_roads AS roads WHERE roads.osm_id=asso.street LIMIT 1) ELSE name END AS name,
house_polygon, house_point
SELECT *
FROM osm_associated AS asso
WHERE house_polygon IS NOT NULL OR house_point IS NOT NULL
WHERE house_polygon_way IS NOT NULL
OR house_polygon_rel IS NOT NULL
OR house_point IS NOT NULL
WITH NO DATA;

-- Update view
Expand All @@ -19,7 +19,8 @@ SET "addr:street" = asso.name,
"source:addr:street" = asso.osm_id
FROM osm_associated_with_street AS asso
WHERE asso.name IS NOT NULL AND "addr:street" IS NULL
AND ( (addr.class='point' AND addr.osm_id=ANY(asso.house_point)) OR
(addr.class='polygon' AND addr.osm_id=ANY(asso.house_polygon)) );
AND ( (addr.class='point' AND addr.osm_id=asso.house_point) OR
(addr.class='polygon' AND addr.osm_id=asso.house_polygon_way) OR
(addr.class='polygon' AND addr.osm_id=asso.house_polygon_rel) );

ANALYSE import.osm_addresses;
20 changes: 11 additions & 9 deletions sql/importDeleteOldEntries.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,56 +4,58 @@ SET client_min_messages TO WARNING;
-- deletes old (deleted and updated entries)
-- osm_addresses
DELETE FROM import.osm_addresses AS addr
USING update_polygon_point AS del
USING update_addresses AS del
WHERE addr.osm_id=del.osm_id
AND addr.class=del.class
AND del.update_type != 'I';

-- osm_admin
DELETE FROM import.osm_admin AS admin
USING update_polygon AS del
USING update_admin AS del
WHERE admin.osm_id=del.osm_id
AND del.update_type != 'I';

-- osm_places
DELETE FROM import.osm_places AS places
USING update_polygon_point AS del
USING update_places AS del
WHERE places.osm_id=del.osm_id
AND places.class=del.class
AND del.update_type != 'I';

-- osm_postcodes
DELETE FROM import.osm_postcode AS postcode
USING update_polygon AS del
USING update_postcodes AS del
WHERE postcode.osm_id=del.osm_id
AND del.update_type != 'I';

-- osm_roads
DELETE FROM import.osm_roads AS roads
USING update_polygon_line AS del
USING update_roads AS del
WHERE roads.osm_id=del.osm_id
AND del.update_type != 'I';

-- delete dependencies in osm_addresses
-- addr:country
UPDATE import.osm_addresses AS addr
SET "addr:country"=NULL, "source:addr:country"=NULL
FROM update_polygon as del
FROM update_admin as del
WHERE "source:addr:country"=del.osm_id
AND del.update_type != 'I';
-- addr:city
UPDATE import.osm_addresses AS addr
SET "addr:city"=NULL, "source:addr:city"=NULL
FROM update_polygon as del
FROM update_admin as del
WHERE "source:addr:city"=del.osm_id
AND del.update_type != 'I';
-- addr:postcode
UPDATE import.osm_addresses AS addr
SET "addr:postcode"=NULL, "source:addr:postcode"=NULL
FROM update_polygon as del
FROM update_postcodes as del
WHERE "source:addr:postcode"=del.osm_id
AND del.update_type != 'I';
-- addr:street
UPDATE import.osm_addresses AS addr
SET "addr:street"=NULL, "source:addr:street"=NULL
FROM update_rels as del
FROM update_asso_street as del
WHERE "source:addr:street"=del.osm_id
AND del.update_type != 'I';
Loading

0 comments on commit 4e564a7

Please sign in to comment.