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,51 +1,58 @@
|
||||
CREATE OR REPLACE FUNCTION brunnel(is_bridge BOOL, is_tunnel BOOL, is_ford BOOL) RETURNS TEXT AS $$
|
||||
SELECT CASE
|
||||
WHEN is_bridge THEN 'bridge'
|
||||
WHEN is_tunnel THEN 'tunnel'
|
||||
WHEN is_ford THEN 'ford'
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION brunnel(is_bridge bool, is_tunnel bool, is_ford bool) RETURNS text AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE STRICT PARALLEL SAFE;
|
||||
SELECT CASE
|
||||
WHEN is_bridge THEN 'bridge'
|
||||
WHEN is_tunnel THEN 'tunnel'
|
||||
WHEN is_ford THEN 'ford'
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
STRICT
|
||||
PARALLEL SAFE;
|
||||
|
||||
-- The classes for highways are derived from the classes used in ClearTables
|
||||
-- https://github.com/ClearTables/ClearTables/blob/master/transportation.lua
|
||||
CREATE OR REPLACE FUNCTION highway_class(highway TEXT, public_transport TEXT, construction TEXT) RETURNS TEXT AS $$
|
||||
SELECT CASE
|
||||
%%FIELD_MAPPING: class %%
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION highway_class(highway text, public_transport text, construction text) RETURNS text AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE PARALLEL SAFE;
|
||||
SELECT CASE
|
||||
%%FIELD_MAPPING: class %%
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
PARALLEL SAFE;
|
||||
|
||||
-- The classes for railways are derived from the classes used in ClearTables
|
||||
-- https://github.com/ClearTables/ClearTables/blob/master/transportation.lua
|
||||
CREATE OR REPLACE FUNCTION railway_class(railway TEXT) RETURNS TEXT AS $$
|
||||
SELECT CASE
|
||||
WHEN railway IN ('rail', 'narrow_gauge', 'preserved', 'funicular') THEN 'rail'
|
||||
WHEN railway IN ('subway', 'light_rail', 'monorail', 'tram') THEN 'transit'
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION railway_class(railway text) RETURNS text AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE STRICT PARALLEL SAFE;
|
||||
SELECT CASE
|
||||
WHEN railway IN ('rail', 'narrow_gauge', 'preserved', 'funicular') THEN 'rail'
|
||||
WHEN railway IN ('subway', 'light_rail', 'monorail', 'tram') THEN 'transit'
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
STRICT
|
||||
PARALLEL SAFE;
|
||||
|
||||
-- Limit service to only the most important values to ensure
|
||||
-- we always know the values of service
|
||||
CREATE OR REPLACE FUNCTION service_value(service TEXT) RETURNS TEXT AS $$
|
||||
SELECT CASE
|
||||
WHEN service IN ('spur', 'yard', 'siding', 'crossover', 'driveway', 'alley', 'parking_aisle') THEN service
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION service_value(service text) RETURNS text AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE STRICT PARALLEL SAFE;
|
||||
SELECT CASE
|
||||
WHEN service IN ('spur', 'yard', 'siding', 'crossover', 'driveway', 'alley', 'parking_aisle') THEN service
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
STRICT
|
||||
PARALLEL SAFE;
|
||||
|
||||
-- Limit surface to only the most important values to ensure
|
||||
-- we always know the values of surface
|
||||
CREATE OR REPLACE FUNCTION surface_value(surface TEXT) RETURNS TEXT AS $$
|
||||
SELECT CASE
|
||||
WHEN surface IN ('paved', 'asphalt', 'cobblestone', 'concrete', 'concrete:lanes', 'concrete:plates', 'metal', 'paving_stones', 'sett', 'unhewn_cobblestone', 'wood') THEN 'paved'
|
||||
WHEN surface IN ('unpaved', 'compacted', 'dirt', 'earth', 'fine_gravel', 'grass', 'grass_paver', 'gravel', 'gravel_turf', 'ground', 'ice', 'mud', 'pebblestone', 'salt', 'sand', 'snow', 'woodchips') THEN 'unpaved'
|
||||
END;
|
||||
CREATE OR REPLACE FUNCTION surface_value(surface text) RETURNS text AS
|
||||
$$
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE STRICT PARALLEL SAFE;
|
||||
SELECT CASE
|
||||
WHEN surface IN ('paved', 'asphalt', 'cobblestone', 'concrete', 'concrete:lanes', 'concrete:plates', 'metal',
|
||||
'paving_stones', 'sett', 'unhewn_cobblestone', 'wood') THEN 'paved'
|
||||
WHEN surface IN ('unpaved', 'compacted', 'dirt', 'earth', 'fine_gravel', 'grass', 'grass_paver', 'gravel',
|
||||
'gravel_turf', 'ground', 'ice', 'mud', 'pebblestone', 'salt', 'sand', 'snow', 'woodchips')
|
||||
THEN 'unpaved'
|
||||
END;
|
||||
$$ LANGUAGE SQL IMMUTABLE
|
||||
STRICT
|
||||
PARALLEL SAFE;
|
||||
|
||||
File diff suppressed because it is too large
Load Diff
@@ -17,113 +17,129 @@ DROP TRIGGER IF EXISTS trigger_refresh ON transportation.updates;
|
||||
|
||||
-- Improve performance of the sql in transportation_name/network_type.sql
|
||||
CREATE INDEX IF NOT EXISTS osm_highway_linestring_highway_idx
|
||||
ON osm_highway_linestring(highway);
|
||||
ON osm_highway_linestring (highway);
|
||||
|
||||
-- Improve performance of the sql below
|
||||
CREATE INDEX IF NOT EXISTS osm_highway_linestring_highway_partial_idx
|
||||
ON osm_highway_linestring(highway)
|
||||
WHERE highway IN ('motorway','trunk', 'primary', 'construction');
|
||||
ON osm_highway_linestring (highway)
|
||||
WHERE highway IN ('motorway', 'trunk', 'primary', 'construction');
|
||||
|
||||
-- etldoc: osm_highway_linestring -> osm_transportation_merge_linestring
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring AS (
|
||||
SELECT
|
||||
(ST_Dump(geometry)).geom AS geometry,
|
||||
NULL::bigint AS osm_id,
|
||||
highway, construction,
|
||||
z_order
|
||||
FROM (
|
||||
SELECT
|
||||
ST_LineMerge(ST_Collect(geometry)) AS geometry,
|
||||
highway, construction,
|
||||
min(z_order) AS z_order
|
||||
FROM osm_highway_linestring
|
||||
WHERE (highway IN ('motorway','trunk', 'primary') OR highway = 'construction' AND construction IN ('motorway','trunk', 'primary'))
|
||||
AND ST_IsValid(geometry)
|
||||
group by highway, construction
|
||||
) AS highway_union
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
-- etldoc: osm_highway_linestring -> osm_transportation_merge_linestring
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring AS
|
||||
(
|
||||
SELECT (ST_Dump(geometry)).geom AS geometry,
|
||||
NULL::bigint AS osm_id,
|
||||
highway,
|
||||
construction,
|
||||
z_order
|
||||
FROM (
|
||||
SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry,
|
||||
highway,
|
||||
construction,
|
||||
min(z_order) AS z_order
|
||||
FROM osm_highway_linestring
|
||||
WHERE (highway IN ('motorway', 'trunk', 'primary') OR
|
||||
highway = 'construction' AND construction IN ('motorway', 'trunk', 'primary'))
|
||||
AND ST_IsValid(geometry)
|
||||
GROUP BY highway, construction
|
||||
) AS highway_union
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_geometry_idx
|
||||
ON osm_transportation_merge_linestring USING gist(geometry);
|
||||
ON osm_transportation_merge_linestring USING gist (geometry);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_highway_partial_idx
|
||||
ON osm_transportation_merge_linestring(highway, construction)
|
||||
WHERE highway IN ('motorway','trunk', 'primary', 'construction');
|
||||
ON osm_transportation_merge_linestring (highway, construction)
|
||||
WHERE highway IN ('motorway', 'trunk', 'primary', 'construction');
|
||||
|
||||
-- etldoc: osm_transportation_merge_linestring -> osm_transportation_merge_linestring_gen3
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen3 AS (
|
||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring
|
||||
WHERE highway IN ('motorway','trunk', 'primary')
|
||||
OR highway = 'construction' AND construction IN ('motorway','trunk', 'primary')
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen3 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring
|
||||
WHERE highway IN ('motorway', 'trunk', 'primary')
|
||||
OR highway = 'construction' AND construction IN ('motorway', 'trunk', 'primary')
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen3_geometry_idx
|
||||
ON osm_transportation_merge_linestring_gen3 USING gist(geometry);
|
||||
ON osm_transportation_merge_linestring_gen3 USING gist (geometry);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen3_highway_partial_idx
|
||||
ON osm_transportation_merge_linestring_gen3(highway, construction)
|
||||
WHERE highway IN ('motorway','trunk', 'primary', 'construction');
|
||||
ON osm_transportation_merge_linestring_gen3 (highway, construction)
|
||||
WHERE highway IN ('motorway', 'trunk', 'primary', 'construction');
|
||||
|
||||
-- etldoc: osm_transportation_merge_linestring_gen3 -> osm_transportation_merge_linestring_gen4
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen4 AS (
|
||||
SELECT ST_Simplify(geometry, 200) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen3
|
||||
WHERE (highway IN ('motorway','trunk', 'primary') OR highway = 'construction' AND construction IN ('motorway','trunk', 'primary'))
|
||||
AND ST_Length(geometry) > 50
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen4 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, 200) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen3
|
||||
WHERE (highway IN ('motorway', 'trunk', 'primary') OR
|
||||
highway = 'construction' AND construction IN ('motorway', 'trunk', 'primary'))
|
||||
AND ST_Length(geometry) > 50
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen4_geometry_idx
|
||||
ON osm_transportation_merge_linestring_gen4 USING gist(geometry);
|
||||
ON osm_transportation_merge_linestring_gen4 USING gist (geometry);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen4_highway_partial_idx
|
||||
ON osm_transportation_merge_linestring_gen4(highway, construction)
|
||||
WHERE highway IN ('motorway','trunk', 'primary', 'construction');
|
||||
ON osm_transportation_merge_linestring_gen4 (highway, construction)
|
||||
WHERE highway IN ('motorway', 'trunk', 'primary', 'construction');
|
||||
|
||||
-- etldoc: osm_transportation_merge_linestring_gen4 -> osm_transportation_merge_linestring_gen5
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen5 AS (
|
||||
SELECT ST_Simplify(geometry, 500) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen4
|
||||
WHERE (highway IN ('motorway','trunk') OR highway = 'construction' AND construction IN ('motorway','trunk'))
|
||||
AND ST_Length(geometry) > 100
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen5 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, 500) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen4
|
||||
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
|
||||
AND ST_Length(geometry) > 100
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen5_geometry_idx
|
||||
ON osm_transportation_merge_linestring_gen5 USING gist(geometry);
|
||||
ON osm_transportation_merge_linestring_gen5 USING gist (geometry);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen5_highway_partial_idx
|
||||
ON osm_transportation_merge_linestring_gen5(highway, construction)
|
||||
WHERE highway IN ('motorway','trunk', 'construction');
|
||||
ON osm_transportation_merge_linestring_gen5 (highway, construction)
|
||||
WHERE highway IN ('motorway', 'trunk', 'construction');
|
||||
|
||||
-- etldoc: osm_transportation_merge_linestring_gen5 -> osm_transportation_merge_linestring_gen6
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen6 AS (
|
||||
SELECT ST_Simplify(geometry, 1000) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen5
|
||||
WHERE (highway IN ('motorway','trunk') OR highway = 'construction' AND construction IN ('motorway','trunk')) AND ST_Length(geometry) > 500
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen6 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, 1000) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen5
|
||||
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
|
||||
AND ST_Length(geometry) > 500
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen6_geometry_idx
|
||||
ON osm_transportation_merge_linestring_gen6 USING gist(geometry);
|
||||
ON osm_transportation_merge_linestring_gen6 USING gist (geometry);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen6_highway_partial_idx
|
||||
ON osm_transportation_merge_linestring_gen6(highway, construction)
|
||||
WHERE highway IN ('motorway','trunk', 'construction');
|
||||
ON osm_transportation_merge_linestring_gen6 (highway, construction)
|
||||
WHERE highway IN ('motorway', 'trunk', 'construction');
|
||||
|
||||
-- etldoc: osm_transportation_merge_linestring_gen6 -> osm_transportation_merge_linestring_gen7
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen7 AS (
|
||||
SELECT ST_Simplify(geometry, 2000) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen6
|
||||
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway') AND ST_Length(geometry) > 1000
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen7 AS
|
||||
(
|
||||
SELECT ST_Simplify(geometry, 2000) AS geometry, osm_id, highway, construction, z_order
|
||||
FROM osm_transportation_merge_linestring_gen6
|
||||
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway')
|
||||
AND ST_Length(geometry) > 1000
|
||||
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen7_geometry_idx
|
||||
ON osm_transportation_merge_linestring_gen7 USING gist(geometry);
|
||||
ON osm_transportation_merge_linestring_gen7 USING gist (geometry);
|
||||
|
||||
|
||||
-- Handle updates
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS transportation;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS transportation.updates(id serial primary key, t text, unique (t));
|
||||
CREATE OR REPLACE FUNCTION transportation.flag() RETURNS trigger AS $$
|
||||
CREATE TABLE IF NOT EXISTS transportation.updates
|
||||
(
|
||||
id serial PRIMARY KEY,
|
||||
t text,
|
||||
UNIQUE (t)
|
||||
);
|
||||
CREATE OR REPLACE FUNCTION transportation.flag() RETURNS trigger AS
|
||||
$$
|
||||
BEGIN
|
||||
INSERT INTO transportation.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||
RETURN null;
|
||||
INSERT INTO transportation.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION transportation.refresh() RETURNS trigger AS
|
||||
$BODY$
|
||||
BEGIN
|
||||
$$
|
||||
BEGIN
|
||||
RAISE NOTICE 'Refresh transportation';
|
||||
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring;
|
||||
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen3;
|
||||
@@ -131,19 +147,21 @@ CREATE OR REPLACE FUNCTION transportation.refresh() RETURNS trigger AS
|
||||
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen5;
|
||||
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen6;
|
||||
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen7;
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM transportation.updates;
|
||||
RETURN null;
|
||||
END;
|
||||
$BODY$
|
||||
language plpgsql;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trigger_flag_transportation
|
||||
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.flag();
|
||||
EXECUTE PROCEDURE transportation.flag();
|
||||
|
||||
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||
AFTER INSERT ON transportation.updates
|
||||
AFTER INSERT
|
||||
ON transportation.updates
|
||||
INITIALLY DEFERRED
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE transportation.refresh();
|
||||
EXECUTE PROCEDURE transportation.refresh();
|
||||
|
||||
Reference in New Issue
Block a user