openmaptiles/layers/housenumber/housenumber_centroid.sql
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

62 lines
1.6 KiB
PL/PgSQL

DROP TRIGGER IF EXISTS trigger_flag ON osm_housenumber_point;
DROP TRIGGER IF EXISTS trigger_refresh ON housenumber.updates;
-- etldoc: osm_housenumber_point -> osm_housenumber_point
CREATE OR REPLACE FUNCTION convert_housenumber_point() RETURNS void AS
$$
BEGIN
UPDATE osm_housenumber_point
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';
END;
$$ LANGUAGE plpgsql;
SELECT convert_housenumber_point();
-- Handle updates
CREATE SCHEMA IF NOT EXISTS housenumber;
CREATE TABLE IF NOT EXISTS housenumber.updates
(
id serial PRIMARY KEY,
t text,
UNIQUE (t)
);
CREATE OR REPLACE FUNCTION housenumber.flag() RETURNS trigger AS
$$
BEGIN
INSERT INTO housenumber.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION housenumber.refresh() RETURNS trigger AS
$$
BEGIN
RAISE LOG 'Refresh housenumber';
PERFORM convert_housenumber_point();
-- noinspection SqlWithoutWhere
DELETE FROM housenumber.updates;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE
ON osm_housenumber_point
FOR EACH STATEMENT
EXECUTE PROCEDURE housenumber.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT
ON housenumber.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE housenumber.refresh();