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>
132 lines
4.4 KiB
PL/PgSQL
132 lines
4.4 KiB
PL/PgSQL
|
|
-- etldoc: layer_transportation_name[shape=record fillcolor=lightpink, style="rounded,filled",
|
|
-- etldoc: label="layer_transportation_name | <z6> z6 | <z7> z7 | <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14_> z14+" ] ;
|
|
|
|
CREATE OR REPLACE FUNCTION layer_transportation_name(bbox geometry, zoom_level integer)
|
|
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text,
|
|
name_de text, tags hstore, ref text, ref_length int, network text, class
|
|
text, subclass text, layer INT, level INT, indoor INT) AS $$
|
|
SELECT 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,
|
|
NULLIF(ref, ''), NULLIF(LENGTH(ref), 0) AS ref_length,
|
|
--TODO: The road network of the road is not yet implemented
|
|
case
|
|
when network is not null
|
|
then network::text
|
|
when length(coalesce(ref, ''))>0
|
|
then 'road'
|
|
end as network,
|
|
highway_class(highway, '', construction) AS class,
|
|
CASE
|
|
WHEN highway IS NOT NULL AND highway_class(highway, '', construction) = 'path'
|
|
THEN highway
|
|
END AS subclass,
|
|
NULLIF(layer, 0) AS layer,
|
|
"level",
|
|
CASE WHEN indoor=TRUE THEN 1 END as indoor
|
|
FROM (
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6
|
|
SELECT *,
|
|
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
|
|
FROM osm_transportation_name_linestring_gen4
|
|
WHERE zoom_level = 6
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7
|
|
SELECT *,
|
|
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
|
|
FROM osm_transportation_name_linestring_gen3
|
|
WHERE zoom_level = 7
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8
|
|
SELECT *,
|
|
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
|
|
FROM osm_transportation_name_linestring_gen2
|
|
WHERE zoom_level = 8
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z9
|
|
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z10
|
|
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11
|
|
SELECT *,
|
|
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
|
|
FROM osm_transportation_name_linestring_gen1
|
|
WHERE zoom_level BETWEEN 9 AND 11
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z12
|
|
SELECT
|
|
geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
"tags",
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order,
|
|
layer,
|
|
"level",
|
|
indoor
|
|
FROM osm_transportation_name_linestring
|
|
WHERE zoom_level = 12
|
|
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
|
|
AND highway_class(highway, '', construction) NOT IN ('minor', 'track', 'path')
|
|
AND NOT highway_is_link(highway)
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z13
|
|
SELECT
|
|
geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
"tags",
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order,
|
|
layer,
|
|
"level",
|
|
indoor
|
|
FROM osm_transportation_name_linestring
|
|
WHERE zoom_level = 13
|
|
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
|
|
AND highway_class(highway, '', construction) NOT IN ('track', 'path')
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z14_
|
|
SELECT
|
|
geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
"tags",
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order,
|
|
layer,
|
|
"level",
|
|
indoor
|
|
FROM osm_transportation_name_linestring
|
|
WHERE zoom_level >= 14
|
|
|
|
) AS zoom_levels
|
|
WHERE geometry && bbox
|
|
ORDER BY z_order ASC;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE PARALLEL SAFE;
|