I would like to reformat all of our SQL to have a concise coding style. This makes it far easier to understand the code for a casual contributor, and lets us spot errors more easily. Most importantly, it makes it much easier to grep (search) the code because it is more likely to be in the same syntax Some key changes: * SQL keywords are always UPPERCASE, e.g. `SELECT WHEN AS END ...` * types, variables, aliases, and field names (identifiers) are always lower case * `LANGUAGE 'plpgsql'` is now `LANGUAGE plpgsql` (no quotes) * a few minor spacing/semicolon cleanups P.S. Per @TomPohys request, `TABLE` is spelled using upper case despite being a type for consistency with PG Docs. Same for `LANGUAGE SQL` vs `LANGUAGE plpgsql`.
147 lines
5.7 KiB
PL/PgSQL
147 lines
5.7 KiB
PL/PgSQL
-- etldoc: layer_place[shape=record fillcolor=lightpink, style="rounded,filled",
|
|
-- etldoc: label="layer_place | <z0_3> z0-3|<z4_7> z4-7|<z8_11> z8-11| <z12_14> z12-z14+" ] ;
|
|
|
|
CREATE OR REPLACE FUNCTION layer_place(bbox geometry, zoom_level int, pixel_width numeric)
|
|
RETURNS TABLE
|
|
(
|
|
osm_id bigint,
|
|
geometry geometry,
|
|
name text,
|
|
name_en text,
|
|
name_de text,
|
|
tags hstore,
|
|
class text,
|
|
"rank" int,
|
|
capital int,
|
|
iso_a2 text
|
|
)
|
|
AS
|
|
$$
|
|
SELECT *
|
|
FROM (
|
|
SELECT
|
|
-- etldoc: osm_continent_point -> layer_place:z0_3
|
|
osm_id * 10 AS osm_id,
|
|
geometry,
|
|
name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
'continent' AS class,
|
|
1 AS "rank",
|
|
NULL::int AS capital,
|
|
NULL::text AS iso_a2
|
|
FROM osm_continent_point
|
|
WHERE geometry && bbox
|
|
AND zoom_level < 4
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
-- etldoc: osm_country_point -> layer_place:z0_3
|
|
-- etldoc: osm_country_point -> layer_place:z4_7
|
|
-- etldoc: osm_country_point -> layer_place:z8_11
|
|
-- etldoc: osm_country_point -> layer_place:z12_14
|
|
osm_id * 10 AS osm_id,
|
|
geometry,
|
|
name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
'country' AS class,
|
|
"rank",
|
|
NULL::int AS capital,
|
|
iso3166_1_alpha_2 AS iso_a2
|
|
FROM osm_country_point
|
|
WHERE geometry && bbox
|
|
AND "rank" <= zoom_level + 1
|
|
AND name <> ''
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
-- etldoc: osm_state_point -> layer_place:z0_3
|
|
-- etldoc: osm_state_point -> layer_place:z4_7
|
|
-- etldoc: osm_state_point -> layer_place:z8_11
|
|
-- etldoc: osm_state_point -> layer_place:z12_14
|
|
osm_id * 10 AS osm_id,
|
|
geometry,
|
|
name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
'state' AS class,
|
|
"rank",
|
|
NULL::int AS capital,
|
|
NULL::text AS iso_a2
|
|
FROM osm_state_point
|
|
WHERE geometry && bbox
|
|
AND name <> ''
|
|
AND ("rank" + 2 <= zoom_level)
|
|
AND (
|
|
zoom_level >= 5 OR
|
|
is_in_country IN ('United Kingdom', 'USA', 'Россия', 'Brasil', 'China', 'India') OR
|
|
is_in_country_code IN ('AU', 'CN', 'IN', 'BR', 'US'))
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
-- etldoc: osm_island_point -> layer_place:z12_14
|
|
osm_id * 10 AS osm_id,
|
|
geometry,
|
|
name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
'island' AS class,
|
|
7 AS "rank",
|
|
NULL::int AS capital,
|
|
NULL::text AS iso_a2
|
|
FROM osm_island_point
|
|
WHERE zoom_level >= 12
|
|
AND geometry && bbox
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
-- etldoc: osm_island_polygon -> layer_place:z8_11
|
|
-- etldoc: osm_island_polygon -> layer_place:z12_14
|
|
osm_id * 10 AS osm_id,
|
|
geometry,
|
|
name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
'island' AS class,
|
|
island_rank(area) AS "rank",
|
|
NULL::int AS capital,
|
|
NULL::text AS iso_a2
|
|
FROM osm_island_polygon
|
|
WHERE geometry && bbox
|
|
AND ((zoom_level = 8 AND island_rank(area) <= 3)
|
|
OR (zoom_level = 9 AND island_rank(area) <= 4)
|
|
OR (zoom_level >= 10))
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
-- etldoc: layer_city -> layer_place:z0_3
|
|
-- etldoc: layer_city -> layer_place:z4_7
|
|
-- etldoc: layer_city -> layer_place:z8_11
|
|
-- etldoc: layer_city -> layer_place:z12_14
|
|
osm_id * 10 AS osm_id,
|
|
geometry,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags,
|
|
place::text AS class,
|
|
"rank",
|
|
capital,
|
|
NULL::text AS iso_a2
|
|
FROM layer_city(bbox, zoom_level, pixel_width)
|
|
ORDER BY "rank" ASC
|
|
) AS place_all
|
|
$$ LANGUAGE SQL IMMUTABLE
|
|
PARALLEL SAFE;
|