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`.
99 lines
3.5 KiB
PL/PgSQL
99 lines
3.5 KiB
PL/PgSQL
-- etldoc: layer_poi[shape=record fillcolor=lightpink, style="rounded,filled",
|
|
-- etldoc: label="layer_poi | <z12> z12 | <z13> z13 | <z14_> z14+" ] ;
|
|
|
|
CREATE OR REPLACE FUNCTION layer_poi(bbox geometry, zoom_level integer, pixel_width numeric)
|
|
RETURNS TABLE
|
|
(
|
|
osm_id bigint,
|
|
geometry geometry,
|
|
name text,
|
|
name_en text,
|
|
name_de text,
|
|
tags hstore,
|
|
class text,
|
|
subclass text,
|
|
agg_stop integer,
|
|
layer integer,
|
|
level integer,
|
|
indoor integer,
|
|
"rank" int
|
|
)
|
|
AS
|
|
$$
|
|
SELECT osm_id_hash AS osm_id,
|
|
geometry,
|
|
NULLIF(name, '') AS name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
tags,
|
|
poi_class(subclass, mapping_key) AS class,
|
|
CASE
|
|
WHEN subclass = 'information'
|
|
THEN NULLIF(information, '')
|
|
WHEN subclass = 'place_of_worship'
|
|
THEN NULLIF(religion, '')
|
|
WHEN subclass = 'pitch'
|
|
THEN NULLIF(sport, '')
|
|
ELSE subclass
|
|
END AS subclass,
|
|
agg_stop,
|
|
NULLIF(layer, 0) AS layer,
|
|
"level",
|
|
CASE WHEN indoor = TRUE THEN 1 END AS indoor,
|
|
row_number() OVER (
|
|
PARTITION BY LabelGrid(geometry, 100 * pixel_width)
|
|
ORDER BY CASE WHEN name = '' THEN 2000 ELSE poi_class_rank(poi_class(subclass, mapping_key)) END ASC
|
|
)::int AS "rank"
|
|
FROM (
|
|
-- etldoc: osm_poi_point -> layer_poi:z12
|
|
-- etldoc: osm_poi_point -> layer_poi:z13
|
|
SELECT *,
|
|
osm_id * 10 AS osm_id_hash
|
|
FROM osm_poi_point
|
|
WHERE geometry && bbox
|
|
AND zoom_level BETWEEN 12 AND 13
|
|
AND ((subclass = 'station' AND mapping_key = 'railway')
|
|
OR subclass IN ('halt', 'ferry_terminal'))
|
|
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_poi_point -> layer_poi:z14_
|
|
SELECT *,
|
|
osm_id * 10 AS osm_id_hash
|
|
FROM osm_poi_point
|
|
WHERE geometry && bbox
|
|
AND zoom_level >= 14
|
|
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_poi_polygon -> layer_poi:z12
|
|
-- etldoc: osm_poi_polygon -> layer_poi:z13
|
|
SELECT *,
|
|
NULL::integer AS agg_stop,
|
|
CASE
|
|
WHEN osm_id < 0 THEN -osm_id * 10 + 4
|
|
ELSE osm_id * 10 + 1
|
|
END AS osm_id_hash
|
|
FROM osm_poi_polygon
|
|
WHERE geometry && bbox
|
|
AND zoom_level BETWEEN 12 AND 13
|
|
AND ((subclass = 'station' AND mapping_key = 'railway')
|
|
OR subclass IN ('halt', 'ferry_terminal'))
|
|
|
|
UNION ALL
|
|
|
|
-- etldoc: osm_poi_polygon -> layer_poi:z14_
|
|
SELECT *,
|
|
NULL::integer AS agg_stop,
|
|
CASE
|
|
WHEN osm_id < 0 THEN -osm_id * 10 + 4
|
|
ELSE osm_id * 10 + 1
|
|
END AS osm_id_hash
|
|
FROM osm_poi_polygon
|
|
WHERE geometry && bbox
|
|
AND zoom_level >= 14
|
|
) AS poi_union
|
|
ORDER BY "rank"
|
|
$$ LANGUAGE SQL IMMUTABLE
|
|
PARALLEL SAFE;
|