openmaptiles/layers/building/building.sql

152 wiersze
8.1 KiB
MySQL
Czysty Zwykły widok Historia

2016-11-30 12:16:20 +00:00
-- etldoc: layer_building[shape=record fillcolor=lightpink, style="rounded,filled",
2016-12-04 01:52:52 +00:00
-- etldoc: label="layer_building | <z13> z13 | <z14_> z14+ " ] ;
2016-11-09 22:39:44 +00:00
CREATE OR REPLACE FUNCTION as_numeric(text) RETURNS NUMERIC AS $$
-- Inspired by http://stackoverflow.com/questions/16195986/isnumeric-with-postgresql/16206123#16206123
DECLARE test NUMERIC;
BEGIN
test = $1::NUMERIC;
RETURN test;
EXCEPTION WHEN others THEN
RETURN -1;
END;
$$ STRICT
LANGUAGE plpgsql IMMUTABLE;
CREATE INDEX IF NOT EXISTS osm_building_relation_building_idx ON osm_building_relation(building) WHERE building = '' AND ST_GeometryType(geometry) = 'ST_Polygon';
CREATE INDEX IF NOT EXISTS osm_building_relation_member_idx ON osm_building_relation(member);
2019-12-06 17:10:22 +00:00
--CREATE INDEX IF NOT EXISTS osm_building_associatedstreet_role_idx ON osm_building_associatedstreet(role) WHERE ST_GeometryType(geometry) = 'ST_Polygon';
--CREATE INDEX IF NOT EXISTS osm_building_street_role_idx ON osm_building_street(role) WHERE ST_GeometryType(geometry) = 'ST_Polygon';
CREATE OR REPLACE VIEW osm_all_buildings AS (
-- etldoc: osm_building_relation -> layer_building:z14_
-- Buildings built from relations
SELECT member AS osm_id,geometry,
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level,
2019-05-24 09:09:09 +00:00
nullif(material, '') AS material,
nullif(colour, '') AS colour,
FALSE as hide_3d
FROM
2019-12-06 17:10:22 +00:00
osm_building_relation WHERE building = '' AND ST_GeometryType(geometry) = 'ST_Polygon'
UNION ALL
-- etldoc: osm_building_associatedstreet -> layer_building:z14_
-- Buildings in associatedstreet relations
SELECT member AS osm_id,geometry,
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level,
2019-05-24 09:09:09 +00:00
nullif(material, '') AS material,
nullif(colour, '') AS colour,
FALSE as hide_3d
FROM
2019-12-06 17:10:22 +00:00
osm_building_associatedstreet WHERE role = 'house' AND ST_GeometryType(geometry) = 'ST_Polygon'
UNION ALL
-- etldoc: osm_building_street -> layer_building:z14_
-- Buildings in street relations
SELECT member AS osm_id,geometry,
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level,
2019-05-24 09:09:09 +00:00
nullif(material, '') AS material,
nullif(colour, '') AS colour,
FALSE as hide_3d
FROM
2019-12-06 17:10:22 +00:00
osm_building_street WHERE role = 'house' AND ST_GeometryType(geometry) = 'ST_Polygon'
UNION ALL
-- etldoc: osm_building_polygon -> layer_building:z14_
-- Buildings that are from multipolygons
SELECT osm_id,geometry,
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level,
2019-05-24 09:09:09 +00:00
nullif(material, '') AS material,
nullif(colour, '') AS colour,
FALSE as hide_3d
FROM
osm_building_polygon obp
-- OSM mulipolygons once imported can give unique postgis polygons with holes, or multi parts polygons
WHERE osm_id < 0 AND ST_GeometryType(geometry) IN ('ST_Polygon', 'ST_MultiPolygon')
UNION ALL
-- etldoc: osm_building_polygon -> layer_building:z14_
-- Standalone buildings
SELECT obp.osm_id,obp.geometry,
COALESCE(nullif(as_numeric(obp.height),-1),nullif(as_numeric(obp.buildingheight),-1)) as height,
COALESCE(nullif(as_numeric(obp.min_height),-1),nullif(as_numeric(obp.buildingmin_height),-1)) as min_height,
COALESCE(nullif(as_numeric(obp.levels),-1),nullif(as_numeric(obp.buildinglevels),-1)) as levels,
COALESCE(nullif(as_numeric(obp.min_level),-1),nullif(as_numeric(obp.buildingmin_level),-1)) as min_level,
2019-05-24 09:09:09 +00:00
nullif(obp.material, '') AS material,
nullif(obp.colour, '') AS colour,
CASE WHEN obr.role='outline' THEN TRUE ELSE FALSE END as hide_3d
FROM
osm_building_polygon obp
LEFT JOIN osm_building_relation obr ON (obr.member = obp.osm_id)
-- Only check for ST_Polygon as we exclude buildings from relations keeping only positive ids
WHERE obp.osm_id >= 0 AND ST_GeometryType(obp.geometry) = 'ST_Polygon'
);
2016-10-08 14:47:24 +00:00
CREATE OR REPLACE FUNCTION layer_building(bbox geometry, zoom_level int)
2019-05-24 09:09:09 +00:00
RETURNS TABLE(geometry geometry, osm_id bigint, render_height int, render_min_height int, colour text, hide_3d boolean) AS $$
SELECT geometry, osm_id, render_height, render_min_height,
2019-05-24 09:09:09 +00:00
COALESCE(colour, CASE material
-- Ordered by count from taginfo
WHEN 'cement_block' THEN '#6a7880'
WHEN 'brick' THEN '#bd8161'
WHEN 'plaster' THEN '#dadbdb'
WHEN 'wood' THEN '#d48741'
WHEN 'concrete' THEN '#d3c2b0'
WHEN 'metal' THEN '#b7b1a6'
WHEN 'stone' THEN '#b4a995'
WHEN 'mud' THEN '#9d8b75'
WHEN 'steel' THEN '#b7b1a6' -- same as metal
WHEN 'glass' THEN '#5a81a0'
WHEN 'traditional' THEN '#bd8161' -- same as brick
WHEN 'masonry' THEN '#bd8161' -- same as brick
WHEN 'Brick' THEN '#bd8161' -- same as brick
WHEN 'tin' THEN '#b7b1a6' -- same as metal
WHEN 'timber_framing' THEN '#b3b0a9'
WHEN 'sandstone' THEN '#b4a995' -- same as stone
WHEN 'clay' THEN '#9d8b75' -- same as mud
END) AS colour,
CASE WHEN hide_3d THEN TRUE END AS hide_3d
FROM (
2016-11-09 22:39:44 +00:00
-- etldoc: osm_building_polygon_gen1 -> layer_building:z13
2016-11-30 12:16:20 +00:00
SELECT
osm_id, geometry,
NULL::int AS render_height, NULL::int AS render_min_height,
2019-05-24 09:09:09 +00:00
NULL::text AS material, NULL::text AS colour,
FALSE AS hide_3d
2016-11-30 12:16:20 +00:00
FROM osm_building_polygon_gen1
2017-04-25 22:03:29 +00:00
WHERE zoom_level = 13 AND geometry && bbox
2016-10-08 14:47:24 +00:00
UNION ALL
2016-11-09 22:39:44 +00:00
-- etldoc: osm_building_polygon -> layer_building:z14_
SELECT DISTINCT ON (osm_id)
osm_id, geometry,
ceil( COALESCE(height, levels*3.66,5))::int AS render_height,
floor(COALESCE(min_height, min_level*3.66,0))::int AS render_min_height,
2019-05-24 09:09:09 +00:00
material,
colour,
hide_3d
FROM osm_all_buildings
WHERE
(levels IS NULL OR levels < 1000) AND
2018-06-13 12:51:25 +00:00
(min_level IS NULL OR min_level < 1000) AND
(height IS NULL OR height < 3000) AND
(min_height IS NULL OR min_height < 3000) AND
zoom_level >= 14 AND geometry && bbox
) AS zoom_levels
2016-10-24 13:44:09 +00:00
ORDER BY render_height ASC, ST_YMin(geometry) DESC;
Parallel capability to layer functions (#728) This PR allows queries to be parallelized on recent versions of Postgres. The `PARALLEL SAFE` modifier has been added to the layer functions and a PLPGSQL function to convert strings into number has been replaced. `PARALLEL SAFE` is a modifier for `CREATE FUNCTION` available since Postgres 9.6, so this change does not break current OpenMapTiles supported database version. More details about this topic [here](https://www.postgresql.org/docs/current/parallel-safety.html) and at the reference documentation for [`CREATE FUNCTION`](https://www.postgresql.org/docs/current/sql-createfunction.html). ### Testing procedure The procedure to test this was: * Imported `spain.pbf` in a clean environment * Dumped the OpenMapTiles database from the Postgres Docker image * Created a clean Postgres 12 database using the default Docker image * Installed `postgis` 3 from the default Debian package and `osml10n` 2.5.8 from the repository (`make`, etc.) * Restored the dump * Lowered the postgres planner parameters for triggering parallel plans: ```sql set parallel_setup_cost = 5; set parallel_tuple_cost = 0.005; ``` * Manually added the `PARALLEL SAFE` modifier to each function involved in layer queries (not on updates or inserting functions). * For each layer, run a testing query to confirm parallel workers were created, something like this: ```sql explain analyze select * from layer_aerodrome_label(tilebbox(8,128,95),10,null) union all select * from layer_aerodrome_label(tilebbox(8,128,97),10,null); ``` * After all the layers were processed and confirmed to start parallel executions, a more complete example was run. This example just retrieves the geometries for all the layers from the same tile but without using any MVT related function. <details><summary>Testing query</summary> ```sql -- Using the function layer_landuse explain analyze select geometry from layer_water(tilebbox(14,8020,6178),14) union all select geometry from layer_waterway(tilebbox(14,8020,6178),14) union all select geometry from layer_landcover(tilebbox(14,8020,6178),14) union all select geometry from layer_landuse(tilebbox(14,8020,6178),14) union all select geometry from layer_mountain_peak(tilebbox(14,8020,6178),14) union all select geometry from layer_park(tilebbox(14,8020,6178),14) union all select geometry from layer_boundary(tilebbox(14,8020,6178),14) union all select geometry from layer_aeroway(tilebbox(14,8020,6178),14) union all select geometry from layer_transportation(tilebbox(14,8020,6178),14) union all select geometry from layer_building(tilebbox(14,8020,6178),14) union all select geometry from layer_water_name(tilebbox(14,8020,6178),14) union all select geometry from layer_transportation_name(tilebbox(14,8020,6178),14) union all select geometry from layer_place(tilebbox(14,8020,6178),14) union all select geometry from layer_housenumber(tilebbox(14,8020,6178),14) union all select geometry from layer_poi(tilebbox(14,8020,6178),14) union all select geometry from layer_aerodrome_label(tilebbox(14,8020,6178),14); ``` </details> You can inspect the execution plan and results on [this page](https://explain.dalibo.com/plan/3z). Also [attaching](https://github.com/openmaptiles/openmaptiles/files/3951822/explain-tile-simple.tar.gz) the query and JSON output for future reference. The website gives a ton of details, but you may want to search for nodes mentioning `workers` or `parallel` like in this area referring to `osm_border` or `osm_aeroway_linestring` entities ![image](https://user-images.githubusercontent.com/188264/70647153-9cac9300-1c48-11ea-96ea-ac7a1e2f4a79.png) ### Next steps Since the execution plan is not showing a parallel append at the top level, meaning it's not running each layer individually, I want to continue experimenting with parameters and queries to see if it's possible to even parallelize more the request. I will post my finding here, even no change in the code should happen. cc. @nyurik Co-authored-by: Yuri Astrakhan <yuriastrakhan@gmail.com>
2020-02-01 00:36:02 +00:00
$$
LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;
-- not handled: where a building outline covers building parts