openmaptiles/layers/boundary/boundary.sql

476 wiersze
19 KiB
MySQL
Czysty Zwykły widok Historia

-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen1 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen1
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen1 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 10) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 10
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen1_idx ON osm_border_linestring_gen1 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen2 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen2
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen2 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen2 AS (
SELECT ST_Simplify(geometry, 20) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 10
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen2_idx ON osm_border_linestring_gen2 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen3 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen3
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen3 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 40) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 8
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen3_idx ON osm_border_linestring_gen3 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen4 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen4
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen4 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen4 AS (
SELECT ST_Simplify(geometry, 80) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 6
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen4_idx ON osm_border_linestring_gen4 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen5 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen5
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen5 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen5 AS (
SELECT ST_Simplify(geometry, 160) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 6
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen5_idx ON osm_border_linestring_gen5 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen6 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen6
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen6 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen6 AS (
SELECT ST_Simplify(geometry, 300) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen6_idx ON osm_border_linestring_gen6 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen7 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen7
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen7 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen7 AS (
SELECT ST_Simplify(geometry, 600) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen7_idx ON osm_border_linestring_gen7 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen8 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen8
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen8 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen8 AS (
SELECT ST_Simplify(geometry, 1200) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen8_idx ON osm_border_linestring_gen8 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen9 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen9
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen9 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen9 AS (
SELECT ST_Simplify(geometry, 2400) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen9_idx ON osm_border_linestring_gen9 USING gist (geometry);
-- This statement can be deleted after the border importer image stops creating this object as a table
DO $$ BEGIN DROP TABLE IF EXISTS osm_border_linestring_gen10 CASCADE; EXCEPTION WHEN wrong_object_type THEN END; $$ language 'plpgsql';
-- etldoc: osm_border_linestring -> osm_border_linestring_gen10
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen10 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen10 AS (
SELECT ST_Simplify(geometry, 4800) AS geometry, osm_id, admin_level, dividing_line, disputed, maritime
FROM osm_border_linestring
WHERE admin_level <= 2
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen10_idx ON osm_border_linestring_gen10 USING gist (geometry);
2019-12-07 11:18:06 +00:00
CREATE OR REPLACE FUNCTION edit_name(name VARCHAR) RETURNS TEXT AS $$
SELECT CASE
WHEN POSITION(' at ' in name) > 0
THEN replace(SUBSTRING(name, POSITION(' at ' in name)+4), ' ', '')
ELSE replace(replace(name,' ',''),'Extentof','')
END;
$$ LANGUAGE SQL IMMUTABLE;
-- etldoc: ne_110m_admin_0_boundary_lines_land -> boundary_z0
CREATE OR REPLACE VIEW boundary_z0 AS (
2019-11-07 17:07:15 +00:00
SELECT geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN true ELSE false END) AS disputed,
2019-12-18 18:31:28 +00:00
NULL::text AS disputed_name,
NULL::text AS claimed_by,
2019-11-07 17:07:15 +00:00
false AS maritime
FROM ne_110m_admin_0_boundary_lines_land
);
-- etldoc: ne_50m_admin_0_boundary_lines_land -> boundary_z1
-- etldoc: ne_50m_admin_1_states_provinces_lines -> boundary_z1
2019-12-11 11:05:42 +00:00
-- etldoc: osm_border_disp_linestring_gen11 -> boundary_z1
CREATE OR REPLACE VIEW boundary_z1 AS (
2019-11-07 17:07:15 +00:00
SELECT geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN true ELSE false END) AS disputed,
NULL AS disputed_name,
NULL AS claimed_by,
2019-11-07 17:07:15 +00:00
false AS maritime
FROM ne_50m_admin_0_boundary_lines_land
UNION ALL
2019-12-07 11:18:06 +00:00
SELECT geometry,
4 AS admin_level,
false AS disputed,
NULL AS disputed_name,
NULL AS claimed_by,
2019-12-07 11:18:06 +00:00
false AS maritime
FROM ne_50m_admin_1_states_provinces_lines
2019-12-11 11:05:42 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-11 11:05:42 +00:00
FROM osm_border_disp_linestring_gen11
);
-- etldoc: ne_50m_admin_0_boundary_lines_land -> boundary_z3
-- etldoc: ne_50m_admin_1_states_provinces_lines -> boundary_z3
2019-12-11 11:05:42 +00:00
-- etldoc: osm_border_disp_linestring_gen11 -> boundary_z3
CREATE OR REPLACE VIEW boundary_z3 AS (
2019-11-07 17:07:15 +00:00
SELECT geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN true ELSE false END) AS disputed,
NULL AS disputed_name,
NULL AS claimed_by,
2019-11-07 17:07:15 +00:00
false AS maritime
FROM ne_50m_admin_0_boundary_lines_land
UNION ALL
2019-12-07 11:18:06 +00:00
SELECT geometry,
4 AS admin_level,
false AS disputed,
NULL AS disputed_name,
NULL AS claimed_by,
2019-12-07 11:18:06 +00:00
false AS maritime
FROM ne_50m_admin_1_states_provinces_lines
2019-12-11 11:05:42 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-11 11:05:42 +00:00
FROM osm_border_disp_linestring_gen11
);
-- etldoc: ne_10m_admin_0_boundary_lines_land -> boundary_z4
-- etldoc: ne_10m_admin_1_states_provinces_lines -> boundary_z4
-- etldoc: osm_border_linestring_gen10 -> boundary_z4
2019-12-11 11:05:42 +00:00
-- etldoc: osm_border_disp_linestring_gen10 -> boundary_z4
2016-10-06 17:35:00 +00:00
CREATE OR REPLACE VIEW boundary_z4 AS (
2019-11-07 17:07:15 +00:00
SELECT geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN true ELSE false END) AS disputed,
NULL AS disputed_name,
NULL AS claimed_by,
2019-11-07 17:07:15 +00:00
false AS maritime
2016-10-06 17:35:00 +00:00
FROM ne_10m_admin_0_boundary_lines_land
2018-04-18 12:57:49 +00:00
WHERE featurecla <> 'Lease limit'
2016-10-06 17:35:00 +00:00
UNION ALL
2019-12-07 11:18:06 +00:00
SELECT geometry,
4 AS admin_level,
false AS disputed,
NULL AS disputed_name,
NULL AS claimed_by,
2019-12-07 11:18:06 +00:00
false AS maritime
FROM ne_10m_admin_1_states_provinces_lines
2019-05-06 16:04:29 +00:00
WHERE min_zoom <= 5
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen10
WHERE maritime=true AND admin_level <= 2
2019-12-11 11:05:42 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-11 11:05:42 +00:00
FROM osm_border_disp_linestring_gen10
2016-10-06 17:35:00 +00:00
);
-- etldoc: osm_border_linestring_gen9 -> boundary_z5
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen9 -> boundary_z5
CREATE OR REPLACE VIEW boundary_z5 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen9
2019-05-03 12:47:30 +00:00
WHERE admin_level <= 4
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen9)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen9
);
-- etldoc: osm_border_linestring_gen8 -> boundary_z6
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen8 -> boundary_z6
2016-11-30 16:56:26 +00:00
CREATE OR REPLACE VIEW boundary_z6 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen8
WHERE admin_level <= 4
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen8)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen8
2016-11-30 16:56:26 +00:00
);
-- etldoc: osm_border_linestring_gen7 -> boundary_z7
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen7 -> boundary_z7
CREATE OR REPLACE VIEW boundary_z7 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen7
WHERE admin_level <= 4
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen7)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen7
);
2016-10-06 17:10:00 +00:00
-- etldoc: osm_border_linestring_gen6 -> boundary_z8
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen6 -> boundary_z8
2016-10-06 17:10:00 +00:00
CREATE OR REPLACE VIEW boundary_z8 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen6
WHERE admin_level <= 4
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen6)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen6
2016-10-10 17:29:50 +00:00
);
-- etldoc: osm_border_linestring_gen5 -> boundary_z9
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen5 -> boundary_z9
2016-10-10 17:29:50 +00:00
CREATE OR REPLACE VIEW boundary_z9 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen5
2016-10-10 17:29:50 +00:00
WHERE admin_level <= 6
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen5)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen5
2016-10-06 17:10:00 +00:00
);
-- etldoc: osm_border_linestring_gen4 -> boundary_z10
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen4 -> boundary_z10
2016-10-06 17:10:00 +00:00
CREATE OR REPLACE VIEW boundary_z10 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen4
2016-10-10 17:29:50 +00:00
WHERE admin_level <= 6
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen4)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen4
);
-- etldoc: osm_border_linestring_gen3 -> boundary_z11
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen3 -> boundary_z11
CREATE OR REPLACE VIEW boundary_z11 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen3
2016-10-10 17:29:50 +00:00
WHERE admin_level <= 8
AND osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen3)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen3
2016-10-06 17:10:00 +00:00
);
2016-10-08 14:30:11 +00:00
-- etldoc: osm_border_linestring_gen2 -> boundary_z12
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen2 -> boundary_z12
CREATE OR REPLACE VIEW boundary_z12 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
FROM osm_border_linestring_gen2
WHERE osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen2)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen2
);
2018-10-16 15:35:47 +00:00
-- etldoc: osm_border_linestring_gen1 -> boundary_z13
2019-12-07 11:18:06 +00:00
-- etldoc: osm_border_disp_linestring_gen1 -> boundary_z13
CREATE OR REPLACE VIEW boundary_z13 AS (
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
disputed,
NULL AS disputed_name,
NULL AS claimed_by,
maritime
2017-01-16 19:11:35 +00:00
FROM osm_border_linestring_gen1
WHERE osm_id NOT IN (SELECT DISTINCT osm_id FROM osm_border_disp_linestring_gen1)
2019-12-07 11:18:06 +00:00
UNION ALL
2019-12-12 08:48:35 +00:00
SELECT geometry,
admin_level,
true AS disputed,
edit_name(name) AS disputed_name,
claimed_by,
maritime
2019-12-07 11:18:06 +00:00
FROM osm_border_disp_linestring_gen1
);
2016-11-30 16:56:26 +00:00
-- etldoc: layer_boundary[shape=record fillcolor=lightpink, style="rounded,filled",
2016-12-04 01:52:52 +00:00
-- etldoc: label="<sql> layer_boundary |<z0> z0 |<z1_2> z1_2 | <z3> z3 | <z4> z4 | <z5> z5 | <z6> z6 | <z7> z7 | <z8> z8 | <z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13+"]
2016-10-08 14:30:11 +00:00
CREATE OR REPLACE FUNCTION layer_boundary (bbox geometry, zoom_level int)
RETURNS TABLE(geometry geometry, admin_level int, disputed int, disputed_name text, claimed_by text, maritime int) AS $$
SELECT geometry, admin_level, disputed::int, disputed_name, claimed_by, maritime::int FROM (
-- etldoc: boundary_z0 -> layer_boundary:z0
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z0 WHERE geometry && bbox AND zoom_level = 0
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z1 -> layer_boundary:z1_2
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z1 WHERE geometry && bbox AND zoom_level BETWEEN 1 AND 2
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z3 -> layer_boundary:z3
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z3 WHERE geometry && bbox AND zoom_level = 3
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z4 -> layer_boundary:z4
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z4 WHERE geometry && bbox AND zoom_level = 4
2016-10-08 14:30:11 +00:00
UNION ALL
2016-11-30 16:56:26 +00:00
-- etldoc: boundary_z5 -> layer_boundary:z5
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z5 WHERE geometry && bbox AND zoom_level = 5
2016-11-30 16:56:26 +00:00
UNION ALL
-- etldoc: boundary_z6 -> layer_boundary:z6
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z6 WHERE geometry && bbox AND zoom_level = 6
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z7 -> layer_boundary:z7
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z7 WHERE geometry && bbox AND zoom_level = 7
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z8 -> layer_boundary:z8
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z8 WHERE geometry && bbox AND zoom_level = 8
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z9 -> layer_boundary:z9
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z9 WHERE geometry && bbox AND zoom_level = 9
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z10 -> layer_boundary:z10
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z10 WHERE geometry && bbox AND zoom_level = 10
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z11 -> layer_boundary:z11
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z11 WHERE geometry && bbox AND zoom_level = 11
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z12 -> layer_boundary:z12
2016-12-21 03:32:34 +00:00
SELECT * FROM boundary_z12 WHERE geometry && bbox AND zoom_level = 12
2016-10-08 14:30:11 +00:00
UNION ALL
-- etldoc: boundary_z13 -> layer_boundary:z13
SELECT * FROM boundary_z13 WHERE geometry && bbox AND zoom_level >= 13
) AS zoom_levels;
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
$$
LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;