Yuri Astrakhan 6457419e0d
NOOP: Format all layer's SQL code (#917)
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`.
2020-06-08 12:19:55 -04:00

152 lines
5.4 KiB
PL/PgSQL

-- etldoc: layer_transportation_name[shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="layer_transportation_name | <z6> z6 | <z7> z7 | <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14_> z14+" ] ;
CREATE OR REPLACE FUNCTION layer_transportation_name(bbox geometry, zoom_level integer)
RETURNS TABLE
(
osm_id bigint,
geometry geometry,
name text,
name_en text,
name_de text,
tags hstore,
ref text,
ref_length int,
network text,
class text,
subclass text,
layer int,
level int,
indoor int
)
AS
$$
SELECT 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,
NULLIF(ref, ''),
NULLIF(LENGTH(ref), 0) AS ref_length,
--TODO: The road network of the road is not yet implemented
CASE
WHEN network IS NOT NULL
THEN network::text
WHEN length(coalesce(ref, '')) > 0
THEN 'road'
END AS network,
highway_class(highway, '', construction) AS class,
CASE
WHEN highway IS NOT NULL AND highway_class(highway, '', construction) = 'path'
THEN highway
END AS subclass,
NULLIF(layer, 0) AS layer,
"level",
CASE WHEN indoor = TRUE THEN 1 END AS indoor
FROM (
-- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen4
WHERE zoom_level = 6
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen3
WHERE zoom_level = 7
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen2
WHERE zoom_level = 8
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z9
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z10
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen1
WHERE zoom_level BETWEEN 9 AND 11
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z12
SELECT geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level = 12
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
AND highway_class(highway, '', construction) NOT IN ('minor', 'track', 'path')
AND NOT highway_is_link(highway)
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z13
SELECT geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level = 13
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
AND highway_class(highway, '', construction) NOT IN ('track', 'path')
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z14_
SELECT geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox
ORDER BY z_order ASC;
$$ LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;