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`.
This commit is contained in:
@@ -1,40 +1,40 @@
|
||||
CREATE OR REPLACE FUNCTION poi_class_rank(class TEXT)
|
||||
RETURNS INT AS $$
|
||||
SELECT CASE class
|
||||
WHEN 'hospital' THEN 20
|
||||
WHEN 'railway' THEN 40
|
||||
WHEN 'bus' THEN 50
|
||||
WHEN 'attraction' THEN 70
|
||||
WHEN 'harbor' THEN 75
|
||||
WHEN 'college' THEN 80
|
||||
WHEN 'school' THEN 85
|
||||
WHEN 'stadium' THEN 90
|
||||
WHEN 'zoo' THEN 95
|
||||
WHEN 'town_hall' THEN 100
|
||||
WHEN 'campsite' THEN 110
|
||||
WHEN 'cemetery' THEN 115
|
||||
WHEN 'park' THEN 120
|
||||
WHEN 'library' THEN 130
|
||||
WHEN 'police' THEN 135
|
||||
WHEN 'post' THEN 140
|
||||
WHEN 'golf' THEN 150
|
||||
WHEN 'shop' THEN 400
|
||||
WHEN 'grocery' THEN 500
|
||||
WHEN 'fast_food' THEN 600
|
||||
WHEN 'clothing_store' THEN 700
|
||||
WHEN 'bar' THEN 800
|
||||
ELSE 1000
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION poi_class_rank(class text)
|
||||
RETURNS int AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE PARALLEL SAFE;
|
||||
SELECT CASE class
|
||||
WHEN 'hospital' THEN 20
|
||||
WHEN 'railway' THEN 40
|
||||
WHEN 'bus' THEN 50
|
||||
WHEN 'attraction' THEN 70
|
||||
WHEN 'harbor' THEN 75
|
||||
WHEN 'college' THEN 80
|
||||
WHEN 'school' THEN 85
|
||||
WHEN 'stadium' THEN 90
|
||||
WHEN 'zoo' THEN 95
|
||||
WHEN 'town_hall' THEN 100
|
||||
WHEN 'campsite' THEN 110
|
||||
WHEN 'cemetery' THEN 115
|
||||
WHEN 'park' THEN 120
|
||||
WHEN 'library' THEN 130
|
||||
WHEN 'police' THEN 135
|
||||
WHEN 'post' THEN 140
|
||||
WHEN 'golf' THEN 150
|
||||
WHEN 'shop' THEN 400
|
||||
WHEN 'grocery' THEN 500
|
||||
WHEN 'fast_food' THEN 600
|
||||
WHEN 'clothing_store' THEN 700
|
||||
WHEN 'bar' THEN 800
|
||||
ELSE 1000
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
PARALLEL SAFE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION poi_class(subclass TEXT, mapping_key TEXT)
|
||||
RETURNS TEXT AS $$
|
||||
SELECT CASE
|
||||
%%FIELD_MAPPING: class %%
|
||||
ELSE subclass
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION poi_class(subclass text, mapping_key text)
|
||||
RETURNS text AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE PARALLEL SAFE;
|
||||
SELECT CASE
|
||||
%%FIELD_MAPPING: class %%
|
||||
ELSE subclass
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
PARALLEL SAFE;
|
||||
|
||||
@@ -1,75 +1,98 @@
|
||||
|
||||
-- etldoc: layer_poi[shape=record fillcolor=lightpink, style="rounded,filled",
|
||||
-- etldoc: label="layer_poi | <z12> z12 | <z13> z13 | <z14_> z14+" ] ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION layer_poi(bbox geometry, zoom_level integer, pixel_width numeric)
|
||||
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, name_de text, tags hstore, class text, subclass text, agg_stop integer, layer integer, level integer, indoor integer, "rank" int) AS $$
|
||||
SELECT osm_id_hash AS osm_id, geometry, NULLIF(name, '') AS name,
|
||||
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
||||
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
||||
tags,
|
||||
poi_class(subclass, mapping_key) AS class,
|
||||
CASE
|
||||
WHEN subclass = 'information'
|
||||
THEN NULLIF(information, '')
|
||||
WHEN subclass = 'place_of_worship'
|
||||
THEN NULLIF(religion, '')
|
||||
WHEN subclass = 'pitch'
|
||||
THEN NULLIF(sport, '')
|
||||
ELSE subclass
|
||||
END AS subclass,
|
||||
agg_stop,
|
||||
NULLIF(layer, 0) AS layer,
|
||||
"level",
|
||||
CASE WHEN indoor=TRUE THEN 1 END as indoor,
|
||||
row_number() OVER (
|
||||
PARTITION BY LabelGrid(geometry, 100 * pixel_width)
|
||||
ORDER BY CASE WHEN name = '' THEN 2000 ELSE poi_class_rank(poi_class(subclass, mapping_key)) END ASC
|
||||
)::int AS "rank"
|
||||
FROM (
|
||||
-- etldoc: osm_poi_point -> layer_poi:z12
|
||||
-- etldoc: osm_poi_point -> layer_poi:z13
|
||||
SELECT *,
|
||||
osm_id*10 AS osm_id_hash FROM osm_poi_point
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level BETWEEN 12 AND 13
|
||||
AND ((subclass='station' AND mapping_key = 'railway')
|
||||
OR subclass IN ('halt', 'ferry_terminal'))
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_poi_point -> layer_poi:z14_
|
||||
SELECT *,
|
||||
osm_id*10 AS osm_id_hash FROM osm_poi_point
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level >= 14
|
||||
|
||||
UNION ALL
|
||||
-- etldoc: osm_poi_polygon -> layer_poi:z12
|
||||
-- etldoc: osm_poi_polygon -> layer_poi:z13
|
||||
SELECT *,
|
||||
NULL::INTEGER AS agg_stop,
|
||||
CASE WHEN osm_id<0 THEN -osm_id*10+4
|
||||
ELSE osm_id*10+1
|
||||
END AS osm_id_hash
|
||||
FROM osm_poi_polygon
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level BETWEEN 12 AND 13
|
||||
AND ((subclass='station' AND mapping_key = 'railway')
|
||||
OR subclass IN ('halt', 'ferry_terminal'))
|
||||
|
||||
UNION ALL
|
||||
-- etldoc: osm_poi_polygon -> layer_poi:z14_
|
||||
SELECT *,
|
||||
NULL::INTEGER AS agg_stop,
|
||||
CASE WHEN osm_id<0 THEN -osm_id*10+4
|
||||
ELSE osm_id*10+1
|
||||
END AS osm_id_hash
|
||||
FROM osm_poi_polygon
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level >= 14
|
||||
) as poi_union
|
||||
ORDER BY "rank"
|
||||
;
|
||||
RETURNS TABLE
|
||||
(
|
||||
osm_id bigint,
|
||||
geometry geometry,
|
||||
name text,
|
||||
name_en text,
|
||||
name_de text,
|
||||
tags hstore,
|
||||
class text,
|
||||
subclass text,
|
||||
agg_stop integer,
|
||||
layer integer,
|
||||
level integer,
|
||||
indoor integer,
|
||||
"rank" int
|
||||
)
|
||||
AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE PARALLEL SAFE;
|
||||
SELECT osm_id_hash AS osm_id,
|
||||
geometry,
|
||||
NULLIF(name, '') AS name,
|
||||
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
||||
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
||||
tags,
|
||||
poi_class(subclass, mapping_key) AS class,
|
||||
CASE
|
||||
WHEN subclass = 'information'
|
||||
THEN NULLIF(information, '')
|
||||
WHEN subclass = 'place_of_worship'
|
||||
THEN NULLIF(religion, '')
|
||||
WHEN subclass = 'pitch'
|
||||
THEN NULLIF(sport, '')
|
||||
ELSE subclass
|
||||
END AS subclass,
|
||||
agg_stop,
|
||||
NULLIF(layer, 0) AS layer,
|
||||
"level",
|
||||
CASE WHEN indoor = TRUE THEN 1 END AS indoor,
|
||||
row_number() OVER (
|
||||
PARTITION BY LabelGrid(geometry, 100 * pixel_width)
|
||||
ORDER BY CASE WHEN name = '' THEN 2000 ELSE poi_class_rank(poi_class(subclass, mapping_key)) END ASC
|
||||
)::int AS "rank"
|
||||
FROM (
|
||||
-- etldoc: osm_poi_point -> layer_poi:z12
|
||||
-- etldoc: osm_poi_point -> layer_poi:z13
|
||||
SELECT *,
|
||||
osm_id * 10 AS osm_id_hash
|
||||
FROM osm_poi_point
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level BETWEEN 12 AND 13
|
||||
AND ((subclass = 'station' AND mapping_key = 'railway')
|
||||
OR subclass IN ('halt', 'ferry_terminal'))
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_poi_point -> layer_poi:z14_
|
||||
SELECT *,
|
||||
osm_id * 10 AS osm_id_hash
|
||||
FROM osm_poi_point
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level >= 14
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_poi_polygon -> layer_poi:z12
|
||||
-- etldoc: osm_poi_polygon -> layer_poi:z13
|
||||
SELECT *,
|
||||
NULL::integer AS agg_stop,
|
||||
CASE
|
||||
WHEN osm_id < 0 THEN -osm_id * 10 + 4
|
||||
ELSE osm_id * 10 + 1
|
||||
END AS osm_id_hash
|
||||
FROM osm_poi_polygon
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level BETWEEN 12 AND 13
|
||||
AND ((subclass = 'station' AND mapping_key = 'railway')
|
||||
OR subclass IN ('halt', 'ferry_terminal'))
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_poi_polygon -> layer_poi:z14_
|
||||
SELECT *,
|
||||
NULL::integer AS agg_stop,
|
||||
CASE
|
||||
WHEN osm_id < 0 THEN -osm_id * 10 + 4
|
||||
ELSE osm_id * 10 + 1
|
||||
END AS osm_id_hash
|
||||
FROM osm_poi_polygon
|
||||
WHERE geometry && bbox
|
||||
AND zoom_level >= 14
|
||||
) AS poi_union
|
||||
ORDER BY "rank"
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
PARALLEL SAFE;
|
||||
|
||||
@@ -1,35 +1,31 @@
|
||||
DROP MATERIALIZED VIEW IF EXISTS osm_poi_stop_centroid CASCADE;
|
||||
CREATE MATERIALIZED VIEW osm_poi_stop_centroid AS (
|
||||
SELECT
|
||||
uic_ref,
|
||||
count(*) as count,
|
||||
CASE WHEN count(*) > 2 THEN ST_Centroid(ST_UNION(geometry)) END AS centroid
|
||||
FROM osm_poi_point
|
||||
WHERE
|
||||
nullif(uic_ref, '') IS NOT NULL
|
||||
AND subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
GROUP BY
|
||||
uic_ref
|
||||
HAVING
|
||||
count(*) > 1
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE MATERIALIZED VIEW osm_poi_stop_centroid AS
|
||||
(
|
||||
SELECT uic_ref,
|
||||
count(*) AS count,
|
||||
CASE WHEN count(*) > 2 THEN ST_Centroid(ST_UNION(geometry)) END AS centroid
|
||||
FROM osm_poi_point
|
||||
WHERE nullif(uic_ref, '') IS NOT NULL
|
||||
AND subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
GROUP BY uic_ref
|
||||
HAVING count(*) > 1
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
|
||||
DROP MATERIALIZED VIEW IF EXISTS osm_poi_stop_rank CASCADE;
|
||||
CREATE MATERIALIZED VIEW osm_poi_stop_rank AS (
|
||||
SELECT
|
||||
p.osm_id,
|
||||
CREATE MATERIALIZED VIEW osm_poi_stop_rank AS
|
||||
(
|
||||
SELECT p.osm_id,
|
||||
-- p.uic_ref,
|
||||
-- p.subclass,
|
||||
ROW_NUMBER()
|
||||
OVER (
|
||||
PARTITION BY p.uic_ref
|
||||
ORDER BY
|
||||
p.subclass :: public_transport_stop_type NULLS LAST,
|
||||
ST_Distance(c.centroid, p.geometry)
|
||||
) AS rk
|
||||
FROM osm_poi_point p
|
||||
INNER JOIN osm_poi_stop_centroid c ON (p.uic_ref = c.uic_ref)
|
||||
WHERE
|
||||
subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
ORDER BY p.uic_ref, rk
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
ROW_NUMBER()
|
||||
OVER (
|
||||
PARTITION BY p.uic_ref
|
||||
ORDER BY
|
||||
p.subclass :: public_transport_stop_type NULLS LAST,
|
||||
ST_Distance(c.centroid, p.geometry)
|
||||
) AS rk
|
||||
FROM osm_poi_point p
|
||||
INNER JOIN osm_poi_stop_centroid c ON (p.uic_ref = c.uic_ref)
|
||||
WHERE subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
ORDER BY p.uic_ref, rk
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
|
||||
@@ -1,11 +1,12 @@
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT 1
|
||||
FROM pg_type
|
||||
WHERE typname = 'public_transport_stop_type') THEN
|
||||
CREATE TYPE public_transport_stop_type AS ENUM (
|
||||
'subway', 'tram_stop', 'bus_station', 'bus_stop'
|
||||
);
|
||||
END IF;
|
||||
END
|
||||
DO
|
||||
$$
|
||||
BEGIN
|
||||
IF NOT EXISTS(SELECT 1
|
||||
FROM pg_type
|
||||
WHERE typname = 'public_transport_stop_type') THEN
|
||||
CREATE TYPE public_transport_stop_type AS enum (
|
||||
'subway', 'tram_stop', 'bus_station', 'bus_stop'
|
||||
);
|
||||
END IF;
|
||||
END
|
||||
$$;
|
||||
|
||||
@@ -2,83 +2,95 @@ DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_point;
|
||||
DROP TRIGGER IF EXISTS trigger_refresh ON poi_point.updates;
|
||||
|
||||
-- etldoc: osm_poi_point -> osm_poi_point
|
||||
CREATE OR REPLACE FUNCTION update_osm_poi_point() RETURNS VOID AS $$
|
||||
CREATE OR REPLACE FUNCTION update_osm_poi_point() RETURNS void AS
|
||||
$$
|
||||
BEGIN
|
||||
UPDATE osm_poi_point
|
||||
UPDATE osm_poi_point
|
||||
SET subclass = 'subway'
|
||||
WHERE station = 'subway' and subclass='station';
|
||||
WHERE station = 'subway'
|
||||
AND subclass = 'station';
|
||||
|
||||
UPDATE osm_poi_point
|
||||
UPDATE osm_poi_point
|
||||
SET subclass = 'halt'
|
||||
WHERE funicular = 'yes' and subclass='station';
|
||||
WHERE funicular = 'yes'
|
||||
AND subclass = 'station';
|
||||
|
||||
UPDATE osm_poi_point
|
||||
SET tags = update_tags(tags, geometry)
|
||||
WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL;
|
||||
UPDATE osm_poi_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_poi_point();
|
||||
|
||||
CREATE OR REPLACE FUNCTION update_osm_poi_point_agg() RETURNS VOID AS $$
|
||||
CREATE OR REPLACE FUNCTION update_osm_poi_point_agg() RETURNS void AS
|
||||
$$
|
||||
BEGIN
|
||||
UPDATE osm_poi_point p
|
||||
SET agg_stop = CASE
|
||||
WHEN p.subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
THEN 1
|
||||
END;
|
||||
UPDATE osm_poi_point p
|
||||
SET agg_stop = CASE
|
||||
WHEN p.subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
THEN 1
|
||||
END;
|
||||
|
||||
UPDATE osm_poi_point p
|
||||
UPDATE osm_poi_point p
|
||||
SET agg_stop = (
|
||||
CASE
|
||||
WHEN p.subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
AND r.rk IS NULL OR r.rk = 1
|
||||
THEN 1
|
||||
END)
|
||||
CASE
|
||||
WHEN p.subclass IN ('bus_stop', 'bus_station', 'tram_stop', 'subway')
|
||||
AND r.rk IS NULL OR r.rk = 1
|
||||
THEN 1
|
||||
END)
|
||||
FROM osm_poi_stop_rank r
|
||||
WHERE p.osm_id = r.osm_id
|
||||
;
|
||||
WHERE p.osm_id = r.osm_id;
|
||||
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
ALTER TABLE osm_poi_point ADD COLUMN IF NOT EXISTS agg_stop INTEGER DEFAULT NULL;
|
||||
ALTER TABLE osm_poi_point
|
||||
ADD COLUMN IF NOT EXISTS agg_stop integer DEFAULT NULL;
|
||||
SELECT update_osm_poi_point_agg();
|
||||
|
||||
-- Handle updates
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS poi_point;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS poi_point.updates(id serial primary key, t text, unique (t));
|
||||
CREATE OR REPLACE FUNCTION poi_point.flag() RETURNS trigger AS $$
|
||||
CREATE TABLE IF NOT EXISTS poi_point.updates
|
||||
(
|
||||
id serial PRIMARY KEY,
|
||||
t text,
|
||||
UNIQUE (t)
|
||||
);
|
||||
CREATE OR REPLACE FUNCTION poi_point.flag() RETURNS trigger AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO poi_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||
RETURN null;
|
||||
INSERT INTO poi_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION poi_point.refresh() RETURNS trigger AS
|
||||
$BODY$
|
||||
BEGIN
|
||||
$$
|
||||
BEGIN
|
||||
RAISE LOG 'Refresh poi_point';
|
||||
PERFORM update_osm_poi_point();
|
||||
REFRESH MATERIALIZED VIEW osm_poi_stop_centroid;
|
||||
REFRESH MATERIALIZED VIEW osm_poi_stop_rank;
|
||||
PERFORM update_osm_poi_point_agg();
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM poi_point.updates;
|
||||
RETURN null;
|
||||
END;
|
||||
$BODY$
|
||||
language plpgsql;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trigger_flag
|
||||
AFTER INSERT OR UPDATE OR DELETE ON osm_poi_point
|
||||
AFTER INSERT OR UPDATE OR DELETE
|
||||
ON osm_poi_point
|
||||
FOR EACH STATEMENT
|
||||
EXECUTE PROCEDURE poi_point.flag();
|
||||
EXECUTE PROCEDURE poi_point.flag();
|
||||
|
||||
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||
AFTER INSERT ON poi_point.updates
|
||||
AFTER INSERT
|
||||
ON poi_point.updates
|
||||
INITIALLY DEFERRED
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE poi_point.refresh();
|
||||
EXECUTE PROCEDURE poi_point.refresh();
|
||||
|
||||
@@ -3,29 +3,33 @@ 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 $$
|
||||
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 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 = 'subway'
|
||||
WHERE station = 'subway'
|
||||
AND subclass = 'station';
|
||||
|
||||
UPDATE osm_poi_polygon
|
||||
UPDATE osm_poi_polygon
|
||||
SET subclass = 'halt'
|
||||
WHERE funicular = 'yes' and subclass='station';
|
||||
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;
|
||||
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;
|
||||
ANALYZE osm_poi_polygon;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
@@ -35,32 +39,40 @@ SELECT update_poi_polygon();
|
||||
|
||||
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 $$
|
||||
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;
|
||||
INSERT INTO poi_polygon.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION poi_polygon.refresh() RETURNS trigger AS
|
||||
$BODY$
|
||||
BEGIN
|
||||
$$
|
||||
BEGIN
|
||||
RAISE LOG 'Refresh poi_polygon';
|
||||
PERFORM update_poi_polygon();
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM poi_polygon.updates;
|
||||
RETURN null;
|
||||
END;
|
||||
$BODY$
|
||||
language plpgsql;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trigger_flag
|
||||
AFTER INSERT OR UPDATE OR DELETE ON osm_poi_polygon
|
||||
AFTER INSERT OR UPDATE OR DELETE
|
||||
ON osm_poi_polygon
|
||||
FOR EACH STATEMENT
|
||||
EXECUTE PROCEDURE poi_polygon.flag();
|
||||
EXECUTE PROCEDURE poi_polygon.flag();
|
||||
|
||||
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||
AFTER INSERT ON poi_polygon.updates
|
||||
AFTER INSERT
|
||||
ON poi_polygon.updates
|
||||
INITIALLY DEFERRED
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE poi_polygon.refresh();
|
||||
EXECUTE PROCEDURE poi_polygon.refresh();
|
||||
|
||||
Reference in New Issue
Block a user