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:
Yuri Astrakhan
2020-06-08 12:19:55 -04:00
committed by GitHub
parent 805d95df09
commit 6457419e0d
46 changed files with 4642 additions and 3124 deletions

View File

@@ -1,131 +1,151 @@
-- etldoc: layer_transportation_name[shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="layer_transportation_name | <z6> z6 | <z7> z7 | <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14_> z14+" ] ;
CREATE OR REPLACE FUNCTION layer_transportation_name(bbox geometry, zoom_level integer)
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text,
name_de text, tags hstore, ref text, ref_length int, network text, class
text, subclass text, layer INT, level INT, indoor INT) AS $$
SELECT 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,
NULLIF(ref, ''), NULLIF(LENGTH(ref), 0) AS ref_length,
--TODO: The road network of the road is not yet implemented
case
when network is not null
then network::text
when length(coalesce(ref, ''))>0
then 'road'
end as network,
highway_class(highway, '', construction) AS class,
CASE
WHEN highway IS NOT NULL AND highway_class(highway, '', construction) = 'path'
THEN highway
END AS subclass,
NULLIF(layer, 0) AS layer,
"level",
CASE WHEN indoor=TRUE THEN 1 END as indoor
FROM (
-- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6
SELECT *,
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen4
WHERE zoom_level = 6
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7
SELECT *,
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen3
WHERE zoom_level = 7
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8
SELECT *,
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen2
WHERE zoom_level = 8
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z9
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z10
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11
SELECT *,
NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen1
WHERE zoom_level BETWEEN 9 AND 11
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z12
SELECT
geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level = 12
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
AND highway_class(highway, '', construction) NOT IN ('minor', 'track', 'path')
AND NOT highway_is_link(highway)
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z13
SELECT
geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level = 13
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
AND highway_class(highway, '', construction) NOT IN ('track', 'path')
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z14_
SELECT
geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox
ORDER BY z_order ASC;
RETURNS TABLE
(
osm_id bigint,
geometry geometry,
name text,
name_en text,
name_de text,
tags hstore,
ref text,
ref_length int,
network text,
class text,
subclass text,
layer int,
level int,
indoor int
)
AS
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;
SELECT 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,
NULLIF(ref, ''),
NULLIF(LENGTH(ref), 0) AS ref_length,
--TODO: The road network of the road is not yet implemented
CASE
WHEN network IS NOT NULL
THEN network::text
WHEN length(coalesce(ref, '')) > 0
THEN 'road'
END AS network,
highway_class(highway, '', construction) AS class,
CASE
WHEN highway IS NOT NULL AND highway_class(highway, '', construction) = 'path'
THEN highway
END AS subclass,
NULLIF(layer, 0) AS layer,
"level",
CASE WHEN indoor = TRUE THEN 1 END AS indoor
FROM (
-- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen4
WHERE zoom_level = 6
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen3
WHERE zoom_level = 7
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen2
WHERE zoom_level = 8
UNION ALL
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z9
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z10
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11
SELECT *,
NULL::int AS layer,
NULL::int AS level,
NULL::boolean AS indoor
FROM osm_transportation_name_linestring_gen1
WHERE zoom_level BETWEEN 9 AND 11
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z12
SELECT geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level = 12
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
AND highway_class(highway, '', construction) NOT IN ('minor', 'track', 'path')
AND NOT highway_is_link(highway)
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z13
SELECT geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level = 13
AND LineLabel(zoom_level, COALESCE(NULLIF(name, ''), ref), geometry)
AND highway_class(highway, '', construction) NOT IN ('track', 'path')
UNION ALL
-- etldoc: osm_transportation_name_linestring -> layer_transportation_name:z14_
SELECT geometry,
osm_id,
name,
name_en,
name_de,
"tags",
ref,
highway,
construction,
network,
z_order,
layer,
"level",
indoor
FROM osm_transportation_name_linestring
WHERE zoom_level >= 14
) AS zoom_levels
WHERE geometry && bbox
ORDER BY z_order ASC;
$$ LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;

View File

@@ -5,26 +5,27 @@ DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen2 CASCADE
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen3 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen4 CASCADE;
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'route_network_type') THEN
CREATE TYPE route_network_type AS ENUM (
'us-interstate', 'us-highway', 'us-state',
'ca-transcanada',
'gb-motorway', 'gb-trunk'
);
END IF;
END
DO
$$
;
BEGIN
IF NOT EXISTS(SELECT 1 FROM pg_type WHERE typname = 'route_network_type') THEN
CREATE TYPE route_network_type AS enum (
'us-interstate', 'us-highway', 'us-state',
'ca-transcanada',
'gb-motorway', 'gb-trunk'
);
END IF;
END
$$;
DO $$
DO
$$
BEGIN
BEGIN
ALTER TABLE osm_route_member ADD COLUMN network_type route_network_type;
ALTER TABLE osm_route_member
ADD COLUMN network_type route_network_type;
EXCEPTION
WHEN duplicate_column THEN RAISE NOTICE 'column network_type already exists in network_type.';
END;
END;
$$
;
$$;

View File

@@ -2,67 +2,69 @@ DROP TRIGGER IF EXISTS trigger_flag_transportation_name ON osm_route_member;
-- create GBR relations (so we can use it in the same way as other relations)
CREATE OR REPLACE FUNCTION update_gbr_route_members() RETURNS VOID AS $$
DECLARE gbr_geom geometry;
CREATE OR REPLACE FUNCTION update_gbr_route_members() RETURNS void AS
$$
DECLARE
gbr_geom geometry;
BEGIN
SELECT st_buffer(geometry, 10000) INTO gbr_geom FROM ne_10m_admin_0_countries where iso_a2 = 'GB';
SELECT st_buffer(geometry, 10000) INTO gbr_geom FROM ne_10m_admin_0_countries WHERE iso_a2 = 'GB';
DELETE FROM osm_route_member WHERE network IN ('omt-gb-motorway', 'omt-gb-trunk');
INSERT INTO osm_route_member (osm_id, member, ref, network)
SELECT 0, osm_id, substring(ref FROM E'^[AM][0-9AM()]+'),
CASE WHEN highway = 'motorway' THEN 'omt-gb-motorway' ELSE 'omt-gb-trunk' END
SELECT 0,
osm_id,
substring(ref FROM E'^[AM][0-9AM()]+'),
CASE WHEN highway = 'motorway' THEN 'omt-gb-motorway' ELSE 'omt-gb-trunk' END
FROM osm_highway_linestring
WHERE
length(ref)>0 AND
ST_Intersects(geometry, gbr_geom) AND
highway IN ('motorway', 'trunk')
;
WHERE length(ref) > 0
AND ST_Intersects(geometry, gbr_geom)
AND highway IN ('motorway', 'trunk');
END;
$$ LANGUAGE plpgsql;
-- etldoc: osm_route_member -> osm_route_member
CREATE OR REPLACE FUNCTION update_osm_route_member() RETURNS VOID AS $$
CREATE OR REPLACE FUNCTION update_osm_route_member() RETURNS void AS
$$
BEGIN
PERFORM update_gbr_route_members();
PERFORM update_gbr_route_members();
-- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes
UPDATE osm_route_member
SET network_type =
CASE
WHEN network = 'US:I' THEN 'us-interstate'::route_network_type
WHEN network = 'US:US' THEN 'us-highway'::route_network_type
WHEN network LIKE 'US:__' THEN 'us-state'::route_network_type
-- https://en.wikipedia.org/wiki/Trans-Canada_Highway
-- TODO: improve hierarchical queries using
-- http://www.openstreetmap.org/relation/1307243
-- however the relation does not cover the whole Trans-Canada_Highway
WHEN
(network = 'CA:transcanada') OR
(network = 'CA:BC:primary' AND ref IN ('16')) OR
(name = 'Yellowhead Highway (AB)' AND ref IN ('16')) OR
(network = 'CA:SK:primary' AND ref IN ('16')) OR
(network = 'CA:ON:primary' AND ref IN ('17', '417')) OR
(name = 'Route Transcanadienne') OR
(network = 'CA:NB:primary' AND ref IN ('2', '16')) OR
(network = 'CA:PE' AND ref IN ('1')) OR
(network = 'CA:NS' AND ref IN ('104', '105')) OR
(network = 'CA:NL:R' AND ref IN ('1')) OR
(name = 'Trans-Canada Highway')
THEN 'ca-transcanada'::route_network_type
WHEN network = 'omt-gb-motorway' THEN 'gb-motorway'::route_network_type
WHEN network = 'omt-gb-trunk' THEN 'gb-trunk'::route_network_type
END
;
-- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes
UPDATE osm_route_member
SET network_type =
CASE
WHEN network = 'US:I' THEN 'us-interstate'::route_network_type
WHEN network = 'US:US' THEN 'us-highway'::route_network_type
WHEN network LIKE 'US:__' THEN 'us-state'::route_network_type
-- https://en.wikipedia.org/wiki/Trans-Canada_Highway
-- TODO: improve hierarchical queries using
-- http://www.openstreetmap.org/relation/1307243
-- however the relation does not cover the whole Trans-Canada_Highway
WHEN
(network = 'CA:transcanada') OR
(network = 'CA:BC:primary' AND ref IN ('16')) OR
(name = 'Yellowhead Highway (AB)' AND ref IN ('16')) OR
(network = 'CA:SK:primary' AND ref IN ('16')) OR
(network = 'CA:ON:primary' AND ref IN ('17', '417')) OR
(name = 'Route Transcanadienne') OR
(network = 'CA:NB:primary' AND ref IN ('2', '16')) OR
(network = 'CA:PE' AND ref IN ('1')) OR
(network = 'CA:NS' AND ref IN ('104', '105')) OR
(network = 'CA:NL:R' AND ref IN ('1')) OR
(name = 'Trans-Canada Highway')
THEN 'ca-transcanada'::route_network_type
WHEN network = 'omt-gb-motorway' THEN 'gb-motorway'::route_network_type
WHEN network = 'omt-gb-trunk' THEN 'gb-trunk'::route_network_type
END;
END;
$$ LANGUAGE plpgsql;
CREATE INDEX IF NOT EXISTS osm_route_member_network_idx ON osm_route_member("network");
CREATE INDEX IF NOT EXISTS osm_route_member_member_idx ON osm_route_member("member");
CREATE INDEX IF NOT EXISTS osm_route_member_name_idx ON osm_route_member("name");
CREATE INDEX IF NOT EXISTS osm_route_member_ref_idx ON osm_route_member("ref");
CREATE INDEX IF NOT EXISTS osm_route_member_network_idx ON osm_route_member ("network");
CREATE INDEX IF NOT EXISTS osm_route_member_member_idx ON osm_route_member ("member");
CREATE INDEX IF NOT EXISTS osm_route_member_name_idx ON osm_route_member ("name");
CREATE INDEX IF NOT EXISTS osm_route_member_ref_idx ON osm_route_member ("ref");
SELECT update_osm_route_member();
CREATE INDEX IF NOT EXISTS osm_route_member_network_type_idx ON osm_route_member("network_type");
CREATE INDEX IF NOT EXISTS osm_route_member_network_type_idx ON osm_route_member ("network_type");

View File

@@ -9,139 +9,194 @@ DROP TRIGGER IF EXISTS trigger_refresh ON transportation_name.updates;
-- etldoc: osm_highway_linestring -> osm_transportation_name_network
-- etldoc: osm_route_member -> osm_transportation_name_network
CREATE MATERIALIZED VIEW osm_transportation_name_network AS (
SELECT
hl.geometry,
hl.osm_id,
CASE WHEN length(hl.name)>15 THEN osml10n_street_abbrev_all(hl.name) ELSE hl.name END AS "name",
CASE WHEN length(hl.name_en)>15 THEN osml10n_street_abbrev_en(hl.name_en) ELSE hl.name_en END AS "name_en",
CASE WHEN length(hl.name_de)>15 THEN osml10n_street_abbrev_de(hl.name_de) ELSE hl.name_de END AS "name_de",
hl.tags,
rm.network_type,
CASE
WHEN (rm.network_type is not null AND nullif(rm.ref::text, '') is not null)
then rm.ref::text
else hl.ref
end as ref,
hl.highway,
hl.construction,
CASE WHEN highway IN ('footway', 'steps') THEN layer END AS layer,
CASE WHEN highway IN ('footway', 'steps') THEN "level" END AS "level",
CASE WHEN highway IN ('footway', 'steps') THEN indoor END AS indoor,
ROW_NUMBER() OVER(PARTITION BY hl.osm_id
ORDER BY rm.network_type) AS "rank",
hl.z_order
FROM osm_highway_linestring hl
left join osm_route_member rm on (rm.member = hl.osm_id)
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist(geometry);
CREATE MATERIALIZED VIEW osm_transportation_name_network AS
(
SELECT hl.geometry,
hl.osm_id,
CASE WHEN length(hl.name) > 15 THEN osml10n_street_abbrev_all(hl.name) ELSE hl.name END AS "name",
CASE WHEN length(hl.name_en) > 15 THEN osml10n_street_abbrev_en(hl.name_en) ELSE hl.name_en END AS "name_en",
CASE WHEN length(hl.name_de) > 15 THEN osml10n_street_abbrev_de(hl.name_de) ELSE hl.name_de END AS "name_de",
hl.tags,
rm.network_type,
CASE
WHEN (rm.network_type IS NOT NULL AND nullif(rm.ref::text, '') IS NOT NULL)
THEN rm.ref::text
ELSE hl.ref
END AS ref,
hl.highway,
hl.construction,
CASE WHEN highway IN ('footway', 'steps') THEN layer END AS layer,
CASE WHEN highway IN ('footway', 'steps') THEN "level" END AS "level",
CASE WHEN highway IN ('footway', 'steps') THEN indoor END AS indoor,
ROW_NUMBER() OVER (PARTITION BY hl.osm_id
ORDER BY rm.network_type) AS "rank",
hl.z_order
FROM osm_highway_linestring hl
LEFT JOIN osm_route_member rm ON (rm.member = hl.osm_id)
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist (geometry);
-- etldoc: osm_transportation_name_network -> osm_transportation_name_linestring
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
SELECT
(ST_Dump(geometry)).geom AS geometry,
NULL::bigint AS osm_id,
name,
name_en,
name_de,
tags || get_basic_names(tags, geometry) AS "tags",
ref,
highway,
construction,
"level",
layer,
indoor,
network_type AS network,
z_order
FROM (
SELECT
ST_LineMerge(ST_Collect(geometry)) AS geometry,
name,
name_en,
name_de,
hstore(string_agg(nullif(slice_language_tags(tags || hstore(ARRAY['name', name, 'name:en', name_en, 'name:de', name_de]))::text, ''), ','))
AS "tags",
ref,
highway,
construction,
"level",
layer,
indoor,
network_type,
min(z_order) AS z_order
FROM osm_transportation_name_network
WHERE ("rank"=1 OR "rank" is null)
AND (name <> '' OR ref <> '')
AND NULLIF(highway, '') IS NOT NULL
group by name, name_en, name_de, ref, highway, construction, "level", layer, indoor, network_type
) AS highway_union
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist(geometry);
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS
(
SELECT (ST_Dump(geometry)).geom AS geometry,
NULL::bigint AS osm_id,
name,
name_en,
name_de,
tags || get_basic_names(tags, geometry) AS "tags",
ref,
highway,
construction,
"level",
layer,
indoor,
network_type AS network,
z_order
FROM (
SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry,
name,
name_en,
name_de,
hstore(string_agg(nullif(slice_language_tags(tags ||
hstore(ARRAY ['name', name, 'name:en', name_en, 'name:de', name_de]))::text,
''), ','))
AS "tags",
ref,
highway,
construction,
"level",
layer,
indoor,
network_type,
min(z_order) AS z_order
FROM osm_transportation_name_network
WHERE ("rank" = 1 OR "rank" IS NULL)
AND (name <> '' OR ref <> '')
AND NULLIF(highway, '') IS NOT NULL
GROUP BY name, name_en, name_de, ref, highway, construction, "level", layer, indoor, network_type
) AS highway_union
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist (geometry);
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_highway_partial_idx
ON osm_transportation_name_linestring(highway, construction)
WHERE highway IN ('motorway','trunk', 'construction');
ON osm_transportation_name_linestring (highway, construction)
WHERE highway IN ('motorway', 'trunk', 'construction');
-- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, name, name_en, name_de, tags, ref, highway, construction, network, z_order
FROM osm_transportation_name_linestring
WHERE (highway IN ('motorway','trunk') OR highway = 'construction' AND construction IN ('motorway','trunk')) AND ST_Length(geometry) > 8000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist(geometry);
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS
(
SELECT ST_Simplify(geometry, 50) AS geometry,
osm_id,
name,
name_en,
name_de,
tags,
ref,
highway,
construction,
network,
z_order
FROM osm_transportation_name_linestring
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
AND ST_Length(geometry) > 8000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist (geometry);
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_highway_partial_idx
ON osm_transportation_name_linestring_gen1(highway, construction)
WHERE highway IN ('motorway','trunk', 'construction');
ON osm_transportation_name_linestring_gen1 (highway, construction)
WHERE highway IN ('motorway', 'trunk', 'construction');
-- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen2 AS (
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, name, name_en, name_de, tags, ref, highway, construction, network, z_order
FROM osm_transportation_name_linestring_gen1
WHERE (highway IN ('motorway','trunk') OR highway = 'construction' AND construction IN ('motorway','trunk')) AND ST_Length(geometry) > 14000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist(geometry);
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen2 AS
(
SELECT ST_Simplify(geometry, 120) AS geometry,
osm_id,
name,
name_en,
name_de,
tags,
ref,
highway,
construction,
network,
z_order
FROM osm_transportation_name_linestring_gen1
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
AND ST_Length(geometry) > 14000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist (geometry);
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_highway_partial_idx
ON osm_transportation_name_linestring_gen2(highway, construction)
WHERE highway IN ('motorway','trunk', 'construction');
ON osm_transportation_name_linestring_gen2 (highway, construction)
WHERE highway IN ('motorway', 'trunk', 'construction');
-- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 200) AS geometry, osm_id, name, name_en, name_de, tags, ref, highway, construction, network, z_order
FROM osm_transportation_name_linestring_gen2
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway') AND ST_Length(geometry) > 20000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry);
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS
(
SELECT ST_Simplify(geometry, 200) AS geometry,
osm_id,
name,
name_en,
name_de,
tags,
ref,
highway,
construction,
network,
z_order
FROM osm_transportation_name_linestring_gen2
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway')
AND ST_Length(geometry) > 20000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist (geometry);
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_highway_partial_idx
ON osm_transportation_name_linestring_gen3(highway, construction)
WHERE highway IN ('motorway', 'construction');
ON osm_transportation_name_linestring_gen3 (highway, construction)
WHERE highway IN ('motorway', 'construction');
-- etldoc: osm_transportation_name_linestring_gen3 -> osm_transportation_name_linestring_gen4
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen4 AS (
SELECT ST_Simplify(geometry, 500) AS geometry, osm_id, name, name_en, name_de, tags, ref, highway, construction, network, z_order
FROM osm_transportation_name_linestring_gen3
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway') AND ST_Length(geometry) > 20000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx ON osm_transportation_name_linestring_gen4 USING gist(geometry);
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen4 AS
(
SELECT ST_Simplify(geometry, 500) AS geometry,
osm_id,
name,
name_en,
name_de,
tags,
ref,
highway,
construction,
network,
z_order
FROM osm_transportation_name_linestring_gen3
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway')
AND ST_Length(geometry) > 20000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx ON osm_transportation_name_linestring_gen4 USING gist (geometry);
-- Handle updates
CREATE SCHEMA IF NOT EXISTS transportation_name;
CREATE TABLE IF NOT EXISTS transportation_name.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION transportation_name.flag() RETURNS trigger AS $$
CREATE TABLE IF NOT EXISTS transportation_name.updates
(
id serial PRIMARY KEY,
t text,
UNIQUE (t)
);
CREATE OR REPLACE FUNCTION transportation_name.flag() RETURNS trigger AS
$$
BEGIN
INSERT INTO transportation_name.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
INSERT INTO transportation_name.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN NULL;
END;
$$ language plpgsql;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS
$BODY$
BEGIN
$$
BEGIN
RAISE LOG 'Refresh transportation_name';
PERFORM update_osm_route_member();
REFRESH MATERIALIZED VIEW osm_transportation_name_network;
@@ -150,24 +205,27 @@ CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen2;
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen3;
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen4;
-- noinspection SqlWithoutWhere
DELETE FROM transportation_name.updates;
RETURN null;
END;
$BODY$
language plpgsql;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_flag_transportation_name
AFTER INSERT OR UPDATE OR DELETE ON osm_route_member
AFTER INSERT OR UPDATE OR DELETE
ON osm_route_member
FOR EACH STATEMENT
EXECUTE PROCEDURE transportation_name.flag();
EXECUTE PROCEDURE transportation_name.flag();
CREATE TRIGGER trigger_flag_transportation_name
AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring
AFTER INSERT OR UPDATE OR DELETE
ON osm_highway_linestring
FOR EACH STATEMENT
EXECUTE PROCEDURE transportation_name.flag();
EXECUTE PROCEDURE transportation_name.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON transportation_name.updates
AFTER INSERT
ON transportation_name.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE transportation_name.refresh();
EXECUTE PROCEDURE transportation_name.refresh();