Functions and triggers for state, country and city ranks
This commit is contained in:
parent
9573aca4f2
commit
c5f05e7c3a
@ -1,6 +1,10 @@
|
|||||||
|
|
||||||
CREATE EXTENSION IF NOT EXISTS unaccent;
|
CREATE EXTENSION IF NOT EXISTS unaccent;
|
||||||
|
|
||||||
|
|
||||||
|
CREATE FUNCTION update_osm_city_point() RETURNS VOID AS $$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
-- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 )
|
-- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 )
|
||||||
-- etldoc: osm_city_point -> osm_city_point
|
-- etldoc: osm_city_point -> osm_city_point
|
||||||
UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL;
|
UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL;
|
||||||
@ -35,4 +39,43 @@ SET "rank" = CASE WHEN scalerank <= 5 THEN scalerank + 1 ELSE scalerank END
|
|||||||
FROM important_city_point AS ne
|
FROM important_city_point AS ne
|
||||||
WHERE osm.osm_id = ne.osm_id;
|
WHERE osm.osm_id = ne.osm_id;
|
||||||
|
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
SELECT update_osm_city_point();
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point("rank");
|
CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point("rank");
|
||||||
|
|
||||||
|
-- Handle updates
|
||||||
|
|
||||||
|
CREATE SCHEMA place_city;
|
||||||
|
|
||||||
|
CREATE TABLE IF NOT EXISTS place_city.updates(id serial primary key, t text, unique (t));
|
||||||
|
CREATE OR REPLACE FUNCTION place_city.flag() RETURNS trigger AS $$
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO place_city.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION place_city.refresh() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
RAISE LOG 'Refresh place_city rank';
|
||||||
|
SELECT update_osm_city_point();
|
||||||
|
DELETE FROM place_city.updates;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql;
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_flag
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_city_point
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE place_city.flag();
|
||||||
|
|
||||||
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||||
|
AFTER INSERT ON place_city.updates
|
||||||
|
INITIALLY DEFERRED
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE PROCEDURE place_city.refresh();
|
||||||
|
|||||||
@ -3,6 +3,9 @@ ALTER TABLE osm_country_point DROP CONSTRAINT IF EXISTS osm_country_point_rank_c
|
|||||||
-- etldoc: ne_10m_admin_0_countries -> osm_country_point
|
-- etldoc: ne_10m_admin_0_countries -> osm_country_point
|
||||||
-- etldoc: osm_country_point -> osm_country_point
|
-- etldoc: osm_country_point -> osm_country_point
|
||||||
|
|
||||||
|
CREATE FUNCTION update_osm_country_point() RETURNS VOID AS $$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
WITH important_country_point AS (
|
WITH important_country_point AS (
|
||||||
SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank
|
SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank
|
||||||
FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm
|
FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm
|
||||||
@ -30,5 +33,44 @@ UPDATE osm_country_point AS osm
|
|||||||
SET "rank" = 1
|
SET "rank" = 1
|
||||||
WHERE "rank" = 0;
|
WHERE "rank" = 0;
|
||||||
|
|
||||||
ALTER TABLE osm_country_point ADD CONSTRAINT osm_country_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6);
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
SELECT update_osm_country_point();
|
||||||
|
|
||||||
|
-- ALTER TABLE osm_country_point ADD CONSTRAINT osm_country_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6);
|
||||||
CREATE INDEX IF NOT EXISTS osm_country_point_rank_idx ON osm_country_point("rank");
|
CREATE INDEX IF NOT EXISTS osm_country_point_rank_idx ON osm_country_point("rank");
|
||||||
|
|
||||||
|
-- Handle updates
|
||||||
|
|
||||||
|
CREATE SCHEMA place_country;
|
||||||
|
|
||||||
|
CREATE TABLE IF NOT EXISTS place_country.updates(id serial primary key, t text, unique (t));
|
||||||
|
CREATE OR REPLACE FUNCTION place_country.flag() RETURNS trigger AS $$
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO place_country.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION place_country.refresh() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
RAISE LOG 'Refresh place_country rank';
|
||||||
|
SELECT update_osm_country_point();
|
||||||
|
DELETE FROM place_country.updates;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql;
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_flag
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_country_point
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE place_country.flag();
|
||||||
|
|
||||||
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||||
|
AFTER INSERT ON place_country.updates
|
||||||
|
INITIALLY DEFERRED
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE PROCEDURE place_country.refresh();
|
||||||
|
|||||||
@ -3,6 +3,9 @@ ALTER TABLE osm_state_point DROP CONSTRAINT IF EXISTS osm_state_point_rank_const
|
|||||||
-- etldoc: ne_10m_admin_1_states_provinces_shp -> osm_state_point
|
-- etldoc: ne_10m_admin_1_states_provinces_shp -> osm_state_point
|
||||||
-- etldoc: osm_state_point -> osm_state_point
|
-- etldoc: osm_state_point -> osm_state_point
|
||||||
|
|
||||||
|
CREATE FUNCTION update_osm_state_point() RETURNS VOID AS $$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
WITH important_state_point AS (
|
WITH important_state_point AS (
|
||||||
SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank, ne.datarank
|
SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank, ne.datarank
|
||||||
FROM ne_10m_admin_1_states_provinces_shp AS ne, osm_state_point AS osm
|
FROM ne_10m_admin_1_states_provinces_shp AS ne, osm_state_point AS osm
|
||||||
@ -26,5 +29,44 @@ WHERE "rank" = 0;
|
|||||||
|
|
||||||
DELETE FROM osm_state_point WHERE "rank" IS NULL;
|
DELETE FROM osm_state_point WHERE "rank" IS NULL;
|
||||||
|
|
||||||
ALTER TABLE osm_state_point ADD CONSTRAINT osm_state_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6);
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
SELECT update_osm_state_point();
|
||||||
|
|
||||||
|
-- ALTER TABLE osm_state_point ADD CONSTRAINT osm_state_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6);
|
||||||
CREATE INDEX IF NOT EXISTS osm_state_point_rank_idx ON osm_state_point("rank");
|
CREATE INDEX IF NOT EXISTS osm_state_point_rank_idx ON osm_state_point("rank");
|
||||||
|
|
||||||
|
-- Handle updates
|
||||||
|
|
||||||
|
CREATE SCHEMA place_state;
|
||||||
|
|
||||||
|
CREATE TABLE IF NOT EXISTS place_state.updates(id serial primary key, t text, unique (t));
|
||||||
|
CREATE OR REPLACE FUNCTION place_state.flag() RETURNS trigger AS $$
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO place_state.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION place_state.refresh() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
RAISE LOG 'Refresh place_state rank';
|
||||||
|
SELECT update_osm_state_point();
|
||||||
|
DELETE FROM place_state.updates;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql;
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_flag
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_state_point
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE place_state.flag();
|
||||||
|
|
||||||
|
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||||
|
AFTER INSERT ON place_state.updates
|
||||||
|
INITIALLY DEFERRED
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE PROCEDURE place_state.refresh();
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user