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  ### 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>
76 lines
2.9 KiB
PL/PgSQL
76 lines
2.9 KiB
PL/PgSQL
|
|
-- etldoc: layer_poi[shape=record fillcolor=lightpink, style="rounded,filled",
|
|
-- etldoc: label="layer_poi | <z12> z12 | <z13> z13 | <z14_> z14+" ] ;
|
|
|
|
CREATE OR REPLACE FUNCTION layer_poi(bbox geometry, zoom_level integer, pixel_width numeric)
|
|
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, name_de text, tags hstore, class text, subclass text, agg_stop integer, layer integer, level integer, indoor integer, "rank" int) AS $$
|
|
SELECT osm_id_hash AS osm_id, geometry, NULLIF(name, '') AS name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
poi_class(subclass, mapping_key) AS class,
|
|
CASE
|
|
WHEN subclass = 'information'
|
|
THEN NULLIF(information, '')
|
|
WHEN subclass = 'place_of_worship'
|
|
THEN NULLIF(religion, '')
|
|
WHEN subclass = 'pitch'
|
|
THEN NULLIF(sport, '')
|
|
ELSE subclass
|
|
END AS subclass,
|
|
agg_stop,
|
|
NULLIF(layer, 0) AS layer,
|
|
"level",
|
|
CASE WHEN indoor=TRUE THEN 1 END as indoor,
|
|
row_number() OVER (
|
|
PARTITION BY LabelGrid(geometry, 100 * pixel_width)
|
|
ORDER BY CASE WHEN name = '' THEN 2000 ELSE poi_class_rank(poi_class(subclass, mapping_key)) END ASC
|
|
)::int AS "rank"
|
|
FROM (
|
|
-- etldoc: osm_poi_point -> layer_poi:z12
|
|
-- etldoc: osm_poi_point -> layer_poi:z13
|
|
SELECT *,
|
|
osm_id*10 AS osm_id_hash FROM osm_poi_point
|
|
WHERE geometry && bbox
|
|
AND zoom_level BETWEEN 12 AND 13
|
|
AND ((subclass='station' AND mapping_key = 'railway')
|
|
OR subclass IN ('halt', 'ferry_terminal'))
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_poi_point -> layer_poi:z14_
|
|
SELECT *,
|
|
osm_id*10 AS osm_id_hash FROM osm_poi_point
|
|
WHERE geometry && bbox
|
|
AND zoom_level >= 14
|
|
|
|
UNION ALL
|
|
-- etldoc: osm_poi_polygon -> layer_poi:z12
|
|
-- etldoc: osm_poi_polygon -> layer_poi:z13
|
|
SELECT *,
|
|
NULL::INTEGER AS agg_stop,
|
|
CASE WHEN osm_id<0 THEN -osm_id*10+4
|
|
ELSE osm_id*10+1
|
|
END AS osm_id_hash
|
|
FROM osm_poi_polygon
|
|
WHERE geometry && bbox
|
|
AND zoom_level BETWEEN 12 AND 13
|
|
AND ((subclass='station' AND mapping_key = 'railway')
|
|
OR subclass IN ('halt', 'ferry_terminal'))
|
|
|
|
UNION ALL
|
|
-- etldoc: osm_poi_polygon -> layer_poi:z14_
|
|
SELECT *,
|
|
NULL::INTEGER AS agg_stop,
|
|
CASE WHEN osm_id<0 THEN -osm_id*10+4
|
|
ELSE osm_id*10+1
|
|
END AS osm_id_hash
|
|
FROM osm_poi_polygon
|
|
WHERE geometry && bbox
|
|
AND zoom_level >= 14
|
|
) as poi_union
|
|
ORDER BY "rank"
|
|
;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE PARALLEL SAFE;
|