openmaptiles/layers/landuse/landuse.sql

380 wiersze
11 KiB
MySQL

-- ne_50m_urban_areas
-- etldoc: ne_50m_urban_areas -> ne_50m_urban_areas_gen_z5
DROP MATERIALIZED VIEW IF EXISTS ne_50m_urban_areas_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_urban_areas_gen_z5 AS
(
SELECT
NULL::bigint AS osm_id,
ST_Simplify(geometry, ZRes(7)) as 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
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_urban_areas_gen_z5_idx ON ne_50m_urban_areas_gen_z5 USING gist (geometry);
2016-10-24 10:02:33 +00:00
-- etldoc: ne_50m_urban_areas_gen_z5 -> ne_50m_urban_areas_gen_z4
DROP MATERIALIZED VIEW IF EXISTS ne_50m_urban_areas_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_urban_areas_gen_z4 AS
(
SELECT
osm_id,
ST_Simplify(geometry, ZRes(6)) as geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM ne_50m_urban_areas_gen_z5
WHERE scalerank <= 2
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_urban_areas_gen_z4_idx ON ne_50m_urban_areas_gen_z4 USING gist (geometry);
2016-10-24 10:02:33 +00:00
-- etldoc: osm_landuse_polygon_gen_z6 -> osm_landuse_polygon_gen_z6_union
-- etldoc: osm_residential_gen_z6 -> osm_landuse_polygon_gen_z6_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z6_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z6
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z6
);
-- etldoc: osm_landuse_polygon_gen_z7 -> osm_landuse_polygon_gen_z7_union
-- etldoc: osm_residential_gen_z7 -> osm_landuse_polygon_gen_z7_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z7_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z7
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z7
);
-- etldoc: osm_landuse_polygon_gen_z8 -> osm_landuse_polygon_gen_z8_union
-- etldoc: osm_residential_gen_z8 -> osm_landuse_polygon_gen_z8_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z8_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z8
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z8
);
-- etldoc: osm_landuse_polygon_gen_z9 -> osm_landuse_polygon_gen_z9_union
-- etldoc: osm_residential_gen_z9 -> osm_landuse_polygon_gen_z9_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z9_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z9
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z9
);
-- etldoc: osm_landuse_polygon_gen_z10 -> osm_landuse_polygon_gen_z10_union
-- etldoc: osm_residential_gen_z10 -> osm_landuse_polygon_gen_z10_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z10_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z10
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z10
);
-- etldoc: osm_landuse_polygon_gen_z11 -> osm_landuse_polygon_gen_z11_union
-- etldoc: osm_residential_gen_z11 -> osm_landuse_polygon_gen_z11_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z11_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z11
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z11
);
-- etldoc: osm_landuse_polygon_gen_z12 -> osm_landuse_polygon_gen_z12_union
-- etldoc: osm_residential_gen_z12 -> osm_landuse_polygon_gen_z12_union
CREATE OR REPLACE VIEW osm_landuse_polygon_gen_z12_union AS
(
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z12
WHERE landuse <> 'residential'
UNION ALL
SELECT NULL::bigint AS osm_id,
geometry,
'residential' AS landuse,
'' AS amenity,
'' AS leisure,
'' AS tourism,
'' AS place,
'' AS waterway
FROM osm_residential_gen_z12
);
-- 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+" ] ;
2016-11-10 01:12:39 +00:00
2016-10-24 10:02:33 +00:00
CREATE OR REPLACE FUNCTION layer_landuse(bbox geometry, zoom_level int)
RETURNS TABLE
(
osm_id bigint,
geometry geometry,
class text
)
AS
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
$$
SELECT osm_id,
geometry,
landuse_unify(
COALESCE(
NULLIF(landuse, ''),
NULLIF(amenity, ''),
NULLIF(leisure, ''),
NULLIF(tourism, ''),
NULLIF(place, ''),
NULLIF(waterway, '')
)) AS class
FROM (
-- etldoc: ne_50m_urban_areas_gen_z4 -> layer_landuse:z4
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM ne_50m_urban_areas_gen_z4
WHERE zoom_level = 4
UNION ALL
-- etldoc: ne_50m_urban_areas_gen_z5 -> layer_landuse:z5
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM ne_50m_urban_areas_gen_z5
WHERE zoom_level = 5
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z6_union -> layer_landuse:z6
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z6_union
WHERE zoom_level = 6
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z7_union -> layer_landuse:z7
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z7_union
WHERE zoom_level = 7
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z8_union -> layer_landuse:z8
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z8_union
WHERE zoom_level = 8
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z9_union -> layer_landuse:z9
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z9_union
WHERE zoom_level = 9
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z10_union -> layer_landuse:z10
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z10_union
WHERE zoom_level = 10
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z11_union -> layer_landuse:z11
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z11_union
WHERE zoom_level = 11
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z12_union -> layer_landuse:z12
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z12_union
WHERE zoom_level = 12
UNION ALL
-- etldoc: osm_landuse_polygon_gen_z13 -> layer_landuse:z13
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon_gen_z13
WHERE zoom_level = 13
UNION ALL
-- etldoc: osm_landuse_polygon -> layer_landuse:z14
SELECT osm_id,
geometry,
landuse,
amenity,
leisure,
tourism,
place,
waterway
FROM osm_landuse_polygon
WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox;
$$ LANGUAGE SQL STABLE
-- STRICT
PARALLEL SAFE;