Skip to content

Commit

Permalink
Improve duplicate geometry removal without using mat views
Browse files Browse the repository at this point in the history
  • Loading branch information
rustprooflabs committed Aug 29, 2022
2 parents 3bf4c20 + 5a75f2f commit 3c98f65
Show file tree
Hide file tree
Showing 20 changed files with 73,327 additions and 40 deletions.
2 changes: 1 addition & 1 deletion Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -66,7 +66,7 @@ docker-exec-default: build-run-docker
-e POSTGRES_USER=postgres \
-u $(CURRENT_UID):$(CURRENT_GID) \
pgosm python3 docker/pgosm_flex.py \
--layerset=default \
--layerset=everything \
--ram=$(RAM) \
--region=north-america/us \
--subregion=district-of-columbia
Expand Down
1 change: 0 additions & 1 deletion flex-config/sql/pgosm-meta.sql
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,6 @@ CREATE OR REPLACE PROCEDURE osm.append_data_finish(skip_nested BOOLEAN = False)
AS $$
BEGIN

REFRESH MATERIALIZED VIEW osm.vplace_polygon;
REFRESH MATERIALIZED VIEW osm.vplace_polygon_subdivide;
REFRESH MATERIALIZED VIEW osm.vpoi_all;

Expand Down
43 changes: 13 additions & 30 deletions flex-config/sql/place.sql
Original file line number Diff line number Diff line change
Expand Up @@ -49,7 +49,9 @@ CREATE INDEX ix_osm_place_line_type ON osm.place_line (osm_type);
CREATE INDEX ix_osm_place_polygon_type ON osm.place_polygon (osm_type);


CREATE VIEW osm.places_in_relations AS

------------------------------------------------
CREATE TEMP TABLE place_polygon_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.place_polygon p_no_rel
WHERE osm_id > 0
Expand All @@ -63,35 +65,16 @@ SELECT p_no_rel.osm_id
)
;

COMMENT ON VIEW osm.places_in_relations IS 'Lists all osm_id values included in a relation''s member_ids list. Technically could contain duplicates, but not a concern with current expected use of this view.';
COMMENT ON COLUMN osm.places_in_relations.osm_id IS 'OpenStreetMap ID. Unique along with geometry type.';


CREATE MATERIALIZED VIEW osm.vplace_polygon AS
SELECT p.*
DELETE
FROM osm.place_polygon p
WHERE NOT EXISTS (
SELECT 1
FROM osm.places_in_relations pir
WHERE p.osm_id = pir.osm_id)
WHERE EXISTS (
SELECT osm_id
FROM place_polygon_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;

CREATE UNIQUE INDEX uix_osm_vplace_polygon_osm_id
ON osm.vplace_polygon (osm_id);
CREATE INDEX gix_osm_vplace_polygon
ON osm.vplace_polygon USING GIST (geom);



COMMENT ON MATERIALIZED VIEW osm.vplace_polygon IS 'Simplified polygon layer removing non-relation geometries when a relation contains it in the member_ids column.';
COMMENT ON COLUMN osm.vplace_polygon.osm_id IS 'OpenStreetMap ID. Unique along with geometry type.';
COMMENT ON COLUMN osm.vplace_polygon.osm_type IS 'Values from place if a place tag exists. If no place tag, values boundary or admin_level indicate the source of the feature.';
COMMENT ON COLUMN osm.vplace_polygon.member_ids IS 'Member IDs making up the full relation. NULL if not a relation. Used to create improved osm.vplace_polygon.';
COMMENT ON COLUMN osm.vplace_polygon.name IS 'Best name option determined by helpers.get_name(). Keys with priority are: name, short_name, alt_name and loc_name. See pgosm-flex/flex-config/helpers.lua for full logic of selection.';
COMMENT ON COLUMN osm.vplace_polygon.admin_level IS 'Value from admin_level if it exists.';

COMMENT ON COLUMN osm.vplace_polygon.boundary IS 'Value from boundary tag. https://wiki.openstreetmap.org/wiki/Boundaries';
COMMENT ON COLUMN osm.vplace_polygon.geom IS 'Geometry loaded by osm2pgsql.';


DROP TABLE IF EXISTS osm.place_polygon_nested;
Expand Down Expand Up @@ -155,7 +138,7 @@ AS $$
SELECT p.osm_id, p.name, p.osm_type,
COALESCE(p.admin_level::INT, 99) AS admin_level,
geom
FROM osm.vplace_polygon p
FROM osm.place_polygon p
WHERE (p.boundary = 'administrative'
OR p.osm_type IN ('neighborhood', 'city', 'suburb', 'town', 'admin_level', 'locality')
)
Expand Down Expand Up @@ -208,13 +191,13 @@ CREATE OR REPLACE PROCEDURE osm.build_nested_admin_polygons(
DROP TABLE IF EXISTS place_batch;
CREATE TEMP TABLE place_batch AS
SELECT p.osm_id, t.nest_level, t.name_path, t.osm_id_path, t.admin_level_path
FROM osm.vplace_polygon p
FROM osm.place_polygon p
INNER JOIN LATERAL (
SELECT COUNT(i.osm_id) AS nest_level,
ARRAY_AGG(i.name ORDER BY COALESCE(i.admin_level::INT, 99::INT) ASC) AS name_path,
ARRAY_AGG(i.osm_id ORDER BY COALESCE(i.admin_level::INT, 99::INT) ASC) AS osm_id_path,
ARRAY_AGG(COALESCE(i.admin_level::INT, 99::INT) ORDER BY i.admin_level ASC) AS admin_level_path
FROM osm.vplace_polygon i
FROM osm.place_polygon i
WHERE ST_Within(p.geom, i.geom)
AND EXISTS (
SELECT 1 FROM places_for_nesting include
Expand Down Expand Up @@ -275,7 +258,7 @@ COMMENT ON PROCEDURE osm.build_nested_admin_polygons IS 'Warning: Expensive proc

CREATE MATERIALIZED VIEW osm.vplace_polygon_subdivide AS
SELECT osm_id, ST_Subdivide(geom) AS geom
FROM osm.vplace_polygon
FROM osm.place_polygon
;
CREATE INDEX gix_osm_vplace_polygon_subdivide
ON osm.vplace_polygon_subdivide USING GIST (geom)
Expand Down
53 changes: 53 additions & 0 deletions flex-config/sql/public_transport.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,3 +66,56 @@ COMMENT ON COLUMN osm.public_transport_point.network IS 'Route, system or operat
COMMENT ON COLUMN osm.public_transport_line.network IS 'Route, system or operator. Usage of network key is widely varied. See https://wiki.openstreetmap.org/wiki/Key:network';
COMMENT ON COLUMN osm.public_transport_polygon.network IS 'Route, system or operator. Usage of network key is widely varied. See https://wiki.openstreetmap.org/wiki/Key:network';




------------------------------------------------
CREATE TEMP TABLE public_transport_polygon_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.public_transport_polygon p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.public_transport_polygon i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;

DELETE
FROM osm.public_transport_polygon p
WHERE EXISTS (
SELECT osm_id
FROM public_transport_polygon_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;


------------------------------------------------

CREATE TEMP TABLE public_transport_line_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.public_transport_line p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.public_transport_line i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;


DELETE
FROM osm.public_transport_line p
WHERE EXISTS (
SELECT osm_id
FROM public_transport_line_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;
54 changes: 54 additions & 0 deletions flex-config/sql/road.sql
Original file line number Diff line number Diff line change
Expand Up @@ -54,3 +54,57 @@ CREATE INDEX ix_osm_road_line_highway ON osm.road_line (osm_type);
CREATE INDEX ix_osm_road_line_major
ON osm.road_line (major)
WHERE major;



------------------------------------------------
CREATE TEMP TABLE road_polygon_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.road_polygon p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.road_polygon i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;


DELETE
FROM osm.road_polygon p
WHERE EXISTS (
SELECT osm_id
FROM road_polygon_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;



------------------------------------------------
CREATE TEMP TABLE road_line_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.road_line p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.road_line i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;

DELETE
FROM osm.road_line p
WHERE EXISTS (
SELECT osm_id
FROM road_line_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;

30 changes: 30 additions & 0 deletions flex-config/sql/road_major.sql
Original file line number Diff line number Diff line change
Expand Up @@ -20,3 +20,33 @@ ALTER TABLE osm.road_major
;

CREATE INDEX ix_osm_road_major_type ON osm.road_major (osm_type);




------------------------------------------------

CREATE TEMP TABLE road_major_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.road_major p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.road_major i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;


DELETE
FROM osm.road_major p
WHERE EXISTS (
SELECT osm_id
FROM road_major_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;

53 changes: 52 additions & 1 deletion flex-config/sql/water.sql
Original file line number Diff line number Diff line change
Expand Up @@ -52,9 +52,60 @@ ALTER TABLE osm.water_polygon
PRIMARY KEY (osm_id)
;


-- osm_type column only has natural/waterway values.
-- Indexing osm_subtype b/c has more selective and seems more likely to be used.
CREATE INDEX ix_osm_water_point_type ON osm.water_point (osm_subtype);
CREATE INDEX ix_osm_water_line_type ON osm.water_line (osm_subtype);
CREATE INDEX ix_osm_water_polygon_type ON osm.water_polygon (osm_subtype);


------------------------------------------------
CREATE TEMP TABLE water_polygon_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.water_polygon p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.water_polygon i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;

DELETE
FROM osm.water_polygon p
WHERE EXISTS (
SELECT osm_id
FROM water_polygon_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;


------------------------------------------------

CREATE TEMP TABLE water_line_in_relations AS
SELECT p_no_rel.osm_id
FROM osm.water_line p_no_rel
WHERE osm_id > 0
AND EXISTS (SELECT *
FROM (SELECT i.osm_id AS relation_id,
jsonb_array_elements_text(i.member_ids)::BIGINT AS member_id
FROM osm.water_line i
WHERE i.osm_id < 0
) rel
WHERE rel.member_id = p_no_rel.osm_id
)
;

DELETE
FROM osm.water_line p
WHERE EXISTS (
SELECT osm_id
FROM water_line_in_relations pir
WHERE p.osm_id = pir.osm_id
)
;

6 changes: 5 additions & 1 deletion flex-config/style/public_transport.lua
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,7 @@ tables.public_transport_line = osm2pgsql.define_table({
{ column = 'lit', type = 'text' },
{ column = 'wheelchair', type = 'text'},
{ column = 'wheelchair_desc', type = 'text'},
{ column = 'member_ids', type = 'jsonb'},
{ column = 'geom', type = 'multilinestring', projection = srid }
}
})
Expand All @@ -73,6 +74,7 @@ tables.public_transport_polygon = osm2pgsql.define_table({
{ column = 'lit', type = 'text' },
{ column = 'wheelchair', type = 'text'},
{ column = 'wheelchair_desc', type = 'text'},
{ column = 'member_ids', type = 'jsonb'},
{ column = 'geom', type = 'multipolygon', projection = srid }
}
})
Expand Down Expand Up @@ -246,12 +248,12 @@ local function public_transport_process_way(object)
end



function public_transport_process_relation(object)
if not is_first_level_public_transport(object.tags) then
return
end

local member_ids = osm2pgsql.way_member_ids(object)
local osm_types = get_osm_type_subtype(object)

local public_transport = object.tags.public_transport
Expand Down Expand Up @@ -290,6 +292,7 @@ function public_transport_process_relation(object)
lit = lit,
wheelchair = wheelchair,
wheelchair_desc = wheelchair_desc,
member_ids = member_ids,
geom = { create = 'area' }
})
else
Expand All @@ -309,6 +312,7 @@ function public_transport_process_relation(object)
lit = lit,
wheelchair = wheelchair,
wheelchair_desc = wheelchair_desc,
member_ids = member_ids,
geom = { create = 'line' }
})
end
Expand Down
Loading

0 comments on commit 3c98f65

Please sign in to comment.