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`.
97 lines
2.4 KiB
PL/PgSQL
97 lines
2.4 KiB
PL/PgSQL
DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_point;
|
|
DROP TRIGGER IF EXISTS trigger_refresh ON poi_point.updates;
|
|
|
|
-- etldoc: osm_poi_point -> osm_poi_point
|
|
CREATE OR REPLACE FUNCTION update_osm_poi_point() RETURNS void AS
|
|
$$
|
|
BEGIN
|
|
UPDATE osm_poi_point
|
|
SET subclass = 'subway'
|
|
WHERE station = 'subway'
|
|
AND subclass = 'station';
|
|
|
|
UPDATE osm_poi_point
|
|
SET subclass = 'halt'
|
|
WHERE funicular = 'yes'
|
|
AND subclass = 'station';
|
|
|
|
UPDATE osm_poi_point
|
|
SET tags = update_tags(tags, geometry)
|
|
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL;
|
|
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
SELECT update_osm_poi_point();
|
|
|
|
CREATE OR REPLACE FUNCTION update_osm_poi_point_agg() RETURNS void AS
|
|
$$
|
|
BEGIN
|
|
UPDATE osm_poi_point p
|
|
SET agg_stop = CASE
|
|
WHEN p.subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
|
THEN 1
|
|
END;
|
|
|
|
UPDATE osm_poi_point p
|
|
SET agg_stop = (
|
|
CASE
|
|
WHEN p.subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
|
AND r.rk IS NULL OR r.rk = 1
|
|
THEN 1
|
|
END)
|
|
FROM osm_poi_stop_rank r
|
|
WHERE p.osm_id = r.osm_id;
|
|
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
ALTER TABLE osm_poi_point
|
|
ADD COLUMN IF NOT EXISTS agg_stop integer DEFAULT NULL;
|
|
SELECT update_osm_poi_point_agg();
|
|
|
|
-- Handle updates
|
|
|
|
CREATE SCHEMA IF NOT EXISTS poi_point;
|
|
|
|
CREATE TABLE IF NOT EXISTS poi_point.updates
|
|
(
|
|
id serial PRIMARY KEY,
|
|
t text,
|
|
UNIQUE (t)
|
|
);
|
|
CREATE OR REPLACE FUNCTION poi_point.flag() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
INSERT INTO poi_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION poi_point.refresh() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
RAISE LOG 'Refresh poi_point';
|
|
PERFORM update_osm_poi_point();
|
|
REFRESH MATERIALIZED VIEW osm_poi_stop_centroid;
|
|
REFRESH MATERIALIZED VIEW osm_poi_stop_rank;
|
|
PERFORM update_osm_poi_point_agg();
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM poi_point.updates;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_flag
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_poi_point
|
|
FOR EACH STATEMENT
|
|
EXECUTE PROCEDURE poi_point.flag();
|
|
|
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
|
AFTER INSERT
|
|
ON poi_point.updates
|
|
INITIALLY DEFERRED
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE poi_point.refresh();
|