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`.
80 lines
2.5 KiB
PL/PgSQL
80 lines
2.5 KiB
PL/PgSQL
DROP TRIGGER IF EXISTS trigger_flag ON osm_marine_point;
|
|
DROP TRIGGER IF EXISTS trigger_refresh ON water_name_marine.updates;
|
|
|
|
CREATE EXTENSION IF NOT EXISTS unaccent;
|
|
|
|
CREATE OR REPLACE FUNCTION update_osm_marine_point() RETURNS void AS
|
|
$$
|
|
BEGIN
|
|
-- etldoc: osm_marine_point -> osm_marine_point
|
|
UPDATE osm_marine_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL;
|
|
|
|
-- etldoc: ne_10m_geography_marine_polys -> osm_marine_point
|
|
-- etldoc: osm_marine_point -> osm_marine_point
|
|
|
|
WITH important_marine_point AS (
|
|
SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank, osm.is_intermittent
|
|
FROM ne_10m_geography_marine_polys AS ne,
|
|
osm_marine_point AS osm
|
|
WHERE trim(regexp_replace(ne.name, '\\s+', ' ', 'g')) ILIKE osm.name
|
|
OR trim(regexp_replace(ne.name, '\\s+', ' ', 'g')) ILIKE osm.tags->'name:en'
|
|
OR trim(regexp_replace(ne.name, '\\s+', ' ', 'g')) ILIKE osm.tags->'name:es'
|
|
OR osm.name ILIKE trim(regexp_replace(ne.name, '\\s+', ' ', 'g')) || ' %'
|
|
)
|
|
UPDATE osm_marine_point AS osm
|
|
SET "rank" = scalerank
|
|
FROM important_marine_point AS ne
|
|
WHERE osm.osm_id = ne.osm_id;
|
|
|
|
UPDATE osm_marine_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_marine_point();
|
|
|
|
CREATE INDEX IF NOT EXISTS osm_marine_point_rank_idx ON osm_marine_point ("rank");
|
|
|
|
-- Handle updates
|
|
CREATE SCHEMA IF NOT EXISTS water_name_marine;
|
|
|
|
CREATE TABLE IF NOT EXISTS water_name_marine.updates
|
|
(
|
|
id serial PRIMARY KEY,
|
|
t text,
|
|
UNIQUE (t)
|
|
);
|
|
CREATE OR REPLACE FUNCTION water_name_marine.flag() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
INSERT INTO water_name_marine.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION water_name_marine.refresh() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
RAISE LOG 'Refresh water_name_marine rank';
|
|
PERFORM update_osm_marine_point();
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM water_name_marine.updates;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trigger_flag
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_marine_point
|
|
FOR EACH STATEMENT
|
|
EXECUTE PROCEDURE water_name_marine.flag();
|
|
|
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
|
AFTER INSERT
|
|
ON water_name_marine.updates
|
|
INITIALLY DEFERRED
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE water_name_marine.refresh();
|