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>
pull/777/head
Jorge Sanz 2020-02-01 01:36:02 +01:00 zatwierdzone przez GitHub
rodzic b1eeff573e
commit ace759590e
Nie znaleziono w bazie danych klucza dla tego podpisu
ID klucza GPG: 4AEE18F83AFDEB23
21 zmienionych plików z 93 dodań i 32 usunięć

Wyświetl plik

@ -36,5 +36,6 @@ $$
round(substring(ele from E'^(-?\\d+)(\\D|$)')::int*3.2808399)::int AS ele_ft
FROM osm_aerodrome_label_point
WHERE geometry && bbox AND zoom_level >= 10;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -40,4 +40,6 @@ RETURNS TABLE(geometry geometry, class text, ref text) AS $$
FROM osm_aeroway_polygon WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;

Wyświetl plik

@ -470,4 +470,6 @@ RETURNS TABLE(geometry geometry, admin_level int, disputed int, disputed_name te
-- etldoc: boundary_z13 -> layer_boundary:z13
SELECT * FROM boundary_z13 WHERE geometry && bbox AND zoom_level >= 13
) AS zoom_levels;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;

Wyświetl plik

@ -142,6 +142,8 @@ RETURNS TABLE(geometry geometry, osm_id bigint, render_height int, render_min_he
zoom_level >= 14 AND geometry && bbox
) AS zoom_levels
ORDER BY render_height ASC, ST_YMin(geometry) DESC;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;
-- not handled: where a building outline covers building parts

Wyświetl plik

@ -7,4 +7,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, housenumber text) AS $$
-- etldoc: osm_housenumber_point -> layer_housenumber:z14_
SELECT osm_id, geometry, housenumber FROM osm_housenumber_point
WHERE zoom_level >= 14 AND geometry && bbox;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -13,7 +13,9 @@ CREATE OR REPLACE FUNCTION landcover_class(subclass VARCHAR) RETURNS TEXT AS $$
SELECT CASE
%%FIELD_MAPPING: class %%
END;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;
-- etldoc: ne_110m_glaciated_areas -> landcover_z0
CREATE OR REPLACE VIEW landcover_z0 AS (
@ -128,4 +130,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, class text, subclass text) AS $$
SELECT *
FROM landcover_z14 WHERE zoom_level >= 14 AND geometry && bbox
) AS zoom_levels;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -108,4 +108,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, class text) AS $$
SELECT * FROM landuse_z14 WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -52,4 +52,6 @@ $$
WHERE zoom_level >= 7 AND (rank <= 5 OR zoom_level >= 14)
ORDER BY "rank" ASC;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -122,4 +122,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, class text, name text, name_en t
WHERE zoom_level >= 14 AND geometry_point && bbox
) AS park_point
) AS park_all;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -4,4 +4,6 @@ RETURNS INT AS $$
WHEN capital IN ('yes', '2') THEN 2
WHEN capital = '4' THEN 4
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;

Wyświetl plik

@ -52,4 +52,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, name_de
OR (zoom_level BETWEEN 11 AND 12 AND (gridrank <= 14 OR "rank" IS NOT NULL))
OR (zoom_level >= 13)
) as city_all;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -6,4 +6,6 @@ CREATE OR REPLACE FUNCTION island_rank(area REAL) RETURNS INT AS $$
WHEN area > 40000000 THEN 3
ELSE 7
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;

Wyświetl plik

@ -96,4 +96,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text,
FROM layer_city(bbox, zoom_level, pixel_width)
ORDER BY "rank" ASC
) AS place_all
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -25,7 +25,9 @@ RETURNS INT AS $$
WHEN 'bar' THEN 800
ELSE 1000
END;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION poi_class(subclass TEXT, mapping_key TEXT)
RETURNS TEXT AS $$
@ -33,4 +35,6 @@ RETURNS TEXT AS $$
%%FIELD_MAPPING: class %%
ELSE subclass
END;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -70,4 +70,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, name_de
) as poi_union
ORDER BY "rank"
;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -4,7 +4,9 @@ CREATE OR REPLACE FUNCTION brunnel(is_bridge BOOL, is_tunnel BOOL, is_ford BOOL)
WHEN is_tunnel THEN 'tunnel'
WHEN is_ford THEN 'ford'
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;
-- The classes for highways are derived from the classes used in ClearTables
-- https://github.com/ClearTables/ClearTables/blob/master/transportation.lua
@ -12,7 +14,9 @@ CREATE OR REPLACE FUNCTION highway_class(highway TEXT, public_transport TEXT, co
SELECT CASE
%%FIELD_MAPPING: class %%
END;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;
-- The classes for railways are derived from the classes used in ClearTables
-- https://github.com/ClearTables/ClearTables/blob/master/transportation.lua
@ -21,7 +25,9 @@ CREATE OR REPLACE FUNCTION railway_class(railway TEXT) RETURNS TEXT AS $$
WHEN railway IN ('rail', 'narrow_gauge', 'preserved', 'funicular') THEN 'rail'
WHEN railway IN ('subway', 'light_rail', 'monorail', 'tram') THEN 'transit'
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;
-- Limit service to only the most important values to ensure
-- we always know the values of service
@ -29,7 +35,9 @@ CREATE OR REPLACE FUNCTION service_value(service TEXT) RETURNS TEXT AS $$
SELECT CASE
WHEN service IN ('spur', 'yard', 'siding', 'crossover', 'driveway', 'alley', 'parking_aisle') THEN service
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;
-- Limit surface to only the most important values to ensure
-- we always know the values of surface
@ -38,4 +46,6 @@ CREATE OR REPLACE FUNCTION surface_value(surface TEXT) RETURNS TEXT AS $$
WHEN surface IN ('paved', 'asphalt', 'cobblestone', 'concrete', 'concrete:lanes', 'concrete:plates', 'metal', 'paving_stones', 'sett', 'unhewn_cobblestone', 'wood') THEN 'paved'
WHEN surface IN ('unpaved', 'compacted', 'dirt', 'earth', 'fine_gravel', 'grass', 'grass_paver', 'gravel', 'gravel_turf', 'ground', 'ice', 'mud', 'pebblestone', 'salt', 'sand', 'snow', 'woodchips') THEN 'unpaved'
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;

Wyświetl plik

@ -1,6 +1,8 @@
CREATE OR REPLACE FUNCTION highway_is_link(highway TEXT) RETURNS BOOLEAN AS $$
SELECT highway LIKE '%_link';
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;
-- etldoc: layer_transportation[shape=record fillcolor=lightpink, style="rounded,filled",
@ -366,4 +368,6 @@ indoor INT, bicycle TEXT, foot TEXT, horse TEXT, mtb_scale TEXT, surface TEXT) A
) AS zoom_levels
WHERE geometry && bbox
ORDER BY z_order ASC;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -126,4 +126,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text,
) AS zoom_levels
WHERE geometry && bbox
ORDER BY z_order ASC;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -48,7 +48,9 @@ CREATE OR REPLACE FUNCTION water_class(waterway TEXT) RETURNS TEXT AS $$
%%FIELD_MAPPING: class %%
ELSE 'river'
END;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION waterway_brunnel(is_bridge BOOL, is_tunnel BOOL) RETURNS TEXT AS $$
@ -56,7 +58,9 @@ CREATE OR REPLACE FUNCTION waterway_brunnel(is_bridge BOOL, is_tunnel BOOL) RETU
WHEN is_bridge THEN 'bridge'
WHEN is_tunnel THEN 'tunnel'
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;
@ -375,4 +379,6 @@ RETURNS TABLE(geometry geometry, class text, brunnel text, intermittent int) AS
SELECT * FROM water_z14 WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -54,4 +54,6 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, name_de
OR (zoom_level >= "rank" AND "rank" IS NOT NULL)
OR (zoom_level >= 8)
);
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;

Wyświetl plik

@ -3,7 +3,9 @@ CREATE OR REPLACE FUNCTION waterway_brunnel(is_bridge BOOL, is_tunnel BOOL) RETU
WHEN is_bridge THEN 'bridge'
WHEN is_tunnel THEN 'tunnel'
END;
$$ LANGUAGE SQL IMMUTABLE STRICT;
$$
LANGUAGE SQL
IMMUTABLE STRICT PARALLEL SAFE;
-- etldoc: ne_110m_rivers_lake_centerlines -> waterway_z3
CREATE OR REPLACE VIEW waterway_z3 AS (
@ -105,4 +107,6 @@ RETURNS TABLE(geometry geometry, class text, name text, name_en text, name_de te
SELECT * FROM waterway_z14 WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox;
$$ LANGUAGE SQL IMMUTABLE;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;