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`.
32 lines
1.1 KiB
SQL
32 lines
1.1 KiB
SQL
DROP MATERIALIZED VIEW IF EXISTS osm_poi_stop_centroid CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_poi_stop_centroid AS
|
|
(
|
|
SELECT uic_ref,
|
|
count(*) AS count,
|
|
CASE WHEN count(*) > 2 THEN ST_Centroid(ST_UNION(geometry)) END AS centroid
|
|
FROM osm_poi_point
|
|
WHERE nullif(uic_ref, '') IS NOT NULL
|
|
AND subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
|
GROUP BY uic_ref
|
|
HAVING count(*) > 1
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
|
|
|
DROP MATERIALIZED VIEW IF EXISTS osm_poi_stop_rank CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_poi_stop_rank AS
|
|
(
|
|
SELECT p.osm_id,
|
|
-- p.uic_ref,
|
|
-- p.subclass,
|
|
ROW_NUMBER()
|
|
OVER (
|
|
PARTITION BY p.uic_ref
|
|
ORDER BY
|
|
p.subclass :: public_transport_stop_type NULLS LAST,
|
|
ST_Distance(c.centroid, p.geometry)
|
|
) AS rk
|
|
FROM osm_poi_point p
|
|
INNER JOIN osm_poi_stop_centroid c ON (p.uic_ref = c.uic_ref)
|
|
WHERE subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
|
ORDER BY p.uic_ref, rk
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|