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`.
92 lines
2.5 KiB
PL/PgSQL
92 lines
2.5 KiB
PL/PgSQL
DROP TRIGGER IF EXISTS trigger_delete_point ON osm_water_polygon;
|
|
DROP TRIGGER IF EXISTS trigger_update_point ON osm_water_polygon;
|
|
DROP TRIGGER IF EXISTS trigger_insert_point ON osm_water_polygon;
|
|
|
|
CREATE OR REPLACE VIEW osm_water_point_view AS
|
|
SELECT wp.osm_id,
|
|
ST_PointOnSurface(wp.geometry) AS geometry,
|
|
wp.name,
|
|
wp.name_en,
|
|
wp.name_de,
|
|
update_tags(wp.tags, ST_PointOnSurface(wp.geometry)) AS tags,
|
|
ST_Area(wp.geometry) AS area,
|
|
wp.is_intermittent
|
|
FROM osm_water_polygon AS wp
|
|
LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
|
|
WHERE ll.osm_id IS NULL
|
|
AND wp.name <> '';
|
|
|
|
-- etldoc: osm_water_polygon -> osm_water_point
|
|
-- etldoc: lake_centerline -> osm_water_point
|
|
CREATE TABLE IF NOT EXISTS osm_water_point AS
|
|
SELECT *
|
|
FROM osm_water_point_view;
|
|
DO
|
|
$$
|
|
BEGIN
|
|
ALTER TABLE osm_water_point
|
|
ADD CONSTRAINT osm_water_point_pk PRIMARY KEY (osm_id);
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
RAISE NOTICE 'primary key osm_water_point_pk already exists in osm_water_point.';
|
|
END;
|
|
$$;
|
|
CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry);
|
|
|
|
-- Handle updates
|
|
|
|
CREATE SCHEMA IF NOT EXISTS water_point;
|
|
|
|
CREATE OR REPLACE FUNCTION water_point.delete() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
DELETE
|
|
FROM osm_water_point
|
|
WHERE osm_water_point.osm_id = OLD.osm_id;
|
|
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION water_point.update() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
UPDATE osm_water_point
|
|
SET (osm_id, geometry, name, name_en, name_de, tags, area, is_intermittent) =
|
|
(SELECT * FROM osm_water_point_view WHERE osm_water_point_view.osm_id = NEW.osm_id)
|
|
WHERE osm_water_point.osm_id = NEW.osm_id;
|
|
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION water_point.insert() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
INSERT INTO osm_water_point
|
|
SELECT *
|
|
FROM osm_water_point_view
|
|
WHERE osm_water_point_view.osm_id = NEW.osm_id;
|
|
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_delete_point
|
|
AFTER DELETE
|
|
ON osm_water_polygon
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_point.delete();
|
|
|
|
CREATE TRIGGER trigger_update_point
|
|
AFTER UPDATE
|
|
ON osm_water_polygon
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_point.update();
|
|
|
|
CREATE TRIGGER trigger_insert_point
|
|
AFTER INSERT
|
|
ON osm_water_polygon
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_point.insert();
|