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`.
79 lines
1.9 KiB
PL/PgSQL
79 lines
1.9 KiB
PL/PgSQL
DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon;
|
|
DROP TRIGGER IF EXISTS trigger_refresh ON poi_polygon.updates;
|
|
|
|
-- etldoc: osm_poi_polygon -> osm_poi_polygon
|
|
|
|
CREATE OR REPLACE FUNCTION update_poi_polygon() RETURNS void AS
|
|
$$
|
|
BEGIN
|
|
UPDATE osm_poi_polygon
|
|
SET geometry =
|
|
CASE
|
|
WHEN ST_NPoints(ST_ConvexHull(geometry)) = ST_NPoints(geometry)
|
|
THEN ST_Centroid(geometry)
|
|
ELSE ST_PointOnSurface(geometry)
|
|
END
|
|
WHERE ST_GeometryType(geometry) <> 'ST_Point';
|
|
|
|
UPDATE osm_poi_polygon
|
|
SET subclass = 'subway'
|
|
WHERE station = 'subway'
|
|
AND subclass = 'station';
|
|
|
|
UPDATE osm_poi_polygon
|
|
SET subclass = 'halt'
|
|
WHERE funicular = 'yes'
|
|
AND subclass = 'station';
|
|
|
|
UPDATE osm_poi_polygon
|
|
SET tags = update_tags(tags, geometry)
|
|
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL;
|
|
|
|
ANALYZE osm_poi_polygon;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
SELECT update_poi_polygon();
|
|
|
|
-- Handle updates
|
|
|
|
CREATE SCHEMA IF NOT EXISTS poi_polygon;
|
|
|
|
CREATE TABLE IF NOT EXISTS poi_polygon.updates
|
|
(
|
|
id serial PRIMARY KEY,
|
|
t text,
|
|
UNIQUE (t)
|
|
);
|
|
CREATE OR REPLACE FUNCTION poi_polygon.flag() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
INSERT INTO poi_polygon.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION poi_polygon.refresh() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
RAISE LOG 'Refresh poi_polygon';
|
|
PERFORM update_poi_polygon();
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM poi_polygon.updates;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_flag
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_poi_polygon
|
|
FOR EACH STATEMENT
|
|
EXECUTE PROCEDURE poi_polygon.flag();
|
|
|
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
|
AFTER INSERT
|
|
ON poi_polygon.updates
|
|
INITIALLY DEFERRED
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE poi_polygon.refresh();
|