openmaptiles/layers/place/layer.sql

102 wiersze
3.8 KiB
MySQL
Czysty Zwykły widok Historia

-- etldoc: layer_place[shape=record fillcolor=lightpink, style="rounded,filled",
2016-12-04 11:09:10 +00:00
-- etldoc: label="layer_place | <z0_3> z0-3|<z4_7> z4-7|<z8_11> z8-11| <z12_14> z12-z14+" ] ;
CREATE OR REPLACE FUNCTION layer_place(bbox geometry, zoom_level int, pixel_width numeric)
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text,
name_de text, tags hstore, class text, "rank" int, capital INT, iso_a2
TEXT) AS $$
SELECT * FROM (
2016-12-04 11:09:10 +00:00
-- etldoc: osm_continent_point -> layer_place:z0_3
SELECT
2017-12-04 09:49:50 +00:00
osm_id*10, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
'continent' AS class, 1 AS "rank", NULL::int AS capital,
NULL::text AS iso_a2
FROM osm_continent_point
WHERE geometry && bbox AND zoom_level < 4
UNION ALL
2016-12-04 11:09:10 +00:00
-- etldoc: osm_country_point -> layer_place:z0_3
-- etldoc: osm_country_point -> layer_place:z4_7
-- etldoc: osm_country_point -> layer_place:z8_11
2016-12-04 11:17:33 +00:00
-- etldoc: osm_country_point -> layer_place:z12_14
SELECT
2017-12-04 09:49:50 +00:00
osm_id*10, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
'country' AS class, "rank", NULL::int AS capital,
iso3166_1_alpha_2 AS iso_a2
FROM osm_country_point
2017-01-18 08:35:28 +00:00
WHERE geometry && bbox AND "rank" <= zoom_level + 1 AND name <> ''
UNION ALL
2016-12-04 11:09:10 +00:00
-- etldoc: osm_state_point -> layer_place:z0_3
-- etldoc: osm_state_point -> layer_place:z4_7
-- etldoc: osm_state_point -> layer_place:z8_11
2016-12-04 11:17:33 +00:00
-- etldoc: osm_state_point -> layer_place:z12_14
SELECT
2017-12-04 09:49:50 +00:00
osm_id*10, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
'state' AS class, "rank", NULL::int AS capital,
NULL::text AS iso_a2
FROM osm_state_point
WHERE geometry && bbox AND
name <> '' AND
("rank" + 2 <= zoom_level) AND (
zoom_level >= 5 OR
is_in_country IN ('United Kingdom', 'USA', 'Россия', 'Brasil', 'China', 'India') OR
is_in_country_code IN ('AU', 'CN', 'IN', 'BR', 'US'))
UNION ALL
2016-12-04 11:09:10 +00:00
2016-12-04 11:17:33 +00:00
-- etldoc: osm_island_point -> layer_place:z12_14
2016-12-02 14:37:48 +00:00
SELECT
2017-12-04 09:49:50 +00:00
osm_id*10, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
'island' AS class, 7 AS "rank", NULL::int AS capital,
NULL::text AS iso_a2
2016-12-02 14:37:48 +00:00
FROM osm_island_point
WHERE zoom_level >= 12
2016-12-02 14:37:48 +00:00
AND geometry && bbox
UNION ALL
2016-12-04 11:09:10 +00:00
-- etldoc: osm_island_polygon -> layer_place:z8_11
2016-12-04 11:17:33 +00:00
-- etldoc: osm_island_polygon -> layer_place:z12_14
2016-12-02 14:37:48 +00:00
SELECT
2017-12-04 09:49:50 +00:00
osm_id*10, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
'island' AS class, island_rank(area) AS "rank", NULL::int AS capital,
NULL::text AS iso_a2
2016-12-02 14:37:48 +00:00
FROM osm_island_polygon
WHERE geometry && bbox AND
((zoom_level = 8 AND island_rank(area) <= 3)
OR (zoom_level = 9 AND island_rank(area) <= 4)
OR (zoom_level >= 10))
UNION ALL
2016-12-04 11:09:10 +00:00
-- etldoc: layer_city -> layer_place:z0_3
-- etldoc: layer_city -> layer_place:z4_7
-- etldoc: layer_city -> layer_place:z8_11
2016-12-04 11:17:33 +00:00
-- etldoc: layer_city -> layer_place:z12_14
SELECT
2017-12-04 09:49:50 +00:00
osm_id*10, geometry, name, name_en, name_de,
tags,
place::text AS class, "rank", capital,
NULL::text AS iso_a2
FROM layer_city(bbox, zoom_level, pixel_width)
ORDER BY "rank" ASC
) AS place_all
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;