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>
114 lines
4.4 KiB
PL/PgSQL
114 lines
4.4 KiB
PL/PgSQL
-- etldoc: ne_50m_urban_areas -> landuse_z4
|
|
CREATE OR REPLACE VIEW landuse_z4 AS (
|
|
SELECT NULL::bigint AS osm_id, geometry, 'residential'::text AS landuse, NULL::text AS amenity, NULL::text AS leisure, NULL::text AS tourism, NULL::text AS place, NULL::text AS waterway, scalerank
|
|
FROM ne_50m_urban_areas
|
|
WHERE scalerank <= 2
|
|
);
|
|
|
|
-- etldoc: ne_50m_urban_areas -> landuse_z5
|
|
CREATE OR REPLACE VIEW landuse_z5 AS (
|
|
SELECT NULL::bigint AS osm_id, geometry, 'residential'::text AS landuse, NULL::text AS amenity, NULL::text AS leisure, NULL::text AS tourism, NULL::text AS place, NULL::text AS waterway, scalerank
|
|
FROM ne_50m_urban_areas
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen7 -> landuse_z6
|
|
CREATE OR REPLACE VIEW landuse_z6 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen7
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen6 -> landuse_z8
|
|
CREATE OR REPLACE VIEW landuse_z8 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen6
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen5 -> landuse_z9
|
|
CREATE OR REPLACE VIEW landuse_z9 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen5
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen4 -> landuse_z10
|
|
CREATE OR REPLACE VIEW landuse_z10 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen4
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen3 -> landuse_z11
|
|
CREATE OR REPLACE VIEW landuse_z11 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen3
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen2 -> landuse_z12
|
|
CREATE OR REPLACE VIEW landuse_z12 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen2
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon_gen1 -> landuse_z13
|
|
CREATE OR REPLACE VIEW landuse_z13 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon_gen1
|
|
);
|
|
|
|
-- etldoc: osm_landuse_polygon -> landuse_z14
|
|
CREATE OR REPLACE VIEW landuse_z14 AS (
|
|
SELECT osm_id, geometry, landuse, amenity, leisure, tourism, place, waterway, NULL::int as scalerank
|
|
FROM osm_landuse_polygon
|
|
);
|
|
|
|
-- etldoc: layer_landuse[shape=record fillcolor=lightpink, style="rounded,filled",
|
|
-- etldoc: label="layer_landuse |<z4> z4|<z5>z5|<z6>z6|<z7>z7| <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11|<z12> z12|<z13> z13|<z14> z14+" ] ;
|
|
|
|
CREATE OR REPLACE FUNCTION layer_landuse(bbox geometry, zoom_level int)
|
|
RETURNS TABLE(osm_id bigint, geometry geometry, class text) AS $$
|
|
SELECT osm_id, geometry,
|
|
COALESCE(
|
|
NULLIF(landuse, ''),
|
|
NULLIF(amenity, ''),
|
|
NULLIF(leisure, ''),
|
|
NULLIF(tourism, ''),
|
|
NULLIF(place, ''),
|
|
NULLIF(waterway, '')
|
|
) AS class
|
|
FROM (
|
|
-- etldoc: landuse_z4 -> layer_landuse:z4
|
|
SELECT * FROM landuse_z4
|
|
WHERE zoom_level = 4
|
|
UNION ALL
|
|
-- etldoc: landuse_z5 -> layer_landuse:z5
|
|
SELECT * FROM landuse_z5
|
|
WHERE zoom_level = 5
|
|
UNION ALL
|
|
-- etldoc: landuse_z6 -> layer_landuse:z6
|
|
-- etldoc: landuse_z6 -> layer_landuse:z7
|
|
SELECT * FROM landuse_z6 WHERE zoom_level BETWEEN 6 AND 7
|
|
UNION ALL
|
|
-- etldoc: landuse_z8 -> layer_landuse:z8
|
|
SELECT * FROM landuse_z8 WHERE zoom_level = 8
|
|
UNION ALL
|
|
-- etldoc: landuse_z9 -> layer_landuse:z9
|
|
SELECT * FROM landuse_z9 WHERE zoom_level = 9
|
|
UNION ALL
|
|
-- etldoc: landuse_z10 -> layer_landuse:z10
|
|
SELECT * FROM landuse_z10 WHERE zoom_level = 10
|
|
UNION ALL
|
|
-- etldoc: landuse_z11 -> layer_landuse:z11
|
|
SELECT * FROM landuse_z11 WHERE zoom_level = 11
|
|
UNION ALL
|
|
-- etldoc: landuse_z12 -> layer_landuse:z12
|
|
SELECT * FROM landuse_z12 WHERE zoom_level = 12
|
|
UNION ALL
|
|
-- etldoc: landuse_z13 -> layer_landuse:z13
|
|
SELECT * FROM landuse_z13 WHERE zoom_level = 13
|
|
UNION ALL
|
|
-- etldoc: landuse_z14 -> layer_landuse:z14
|
|
SELECT * FROM landuse_z14 WHERE zoom_level >= 14
|
|
) AS zoom_levels
|
|
WHERE geometry && bbox;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE PARALLEL SAFE;
|