Initial materialized views and triggers
This commit is contained in:
parent
4350aa11f9
commit
c64170d9be
@ -1,16 +1,11 @@
|
|||||||
|
|
||||||
DROP TABLE IF EXISTS osm_transportation_name_linestring CASCADE;
|
|
||||||
DROP TABLE IF EXISTS osm_transportation_name_linestring_gen1 CASCADE;
|
|
||||||
DROP TABLE IF EXISTS osm_transportation_name_linestring_gen2 CASCADE;
|
|
||||||
DROP TABLE IF EXISTS osm_transportation_name_linestring_gen3 CASCADE;
|
|
||||||
|
|
||||||
-- Instead of using relations to find out the road names we
|
-- Instead of using relations to find out the road names we
|
||||||
-- stitch together the touching ways with the same name
|
-- stitch together the touching ways with the same name
|
||||||
-- to allow for nice label rendering
|
-- to allow for nice label rendering
|
||||||
-- Because this works well for roads that do not have relations as well
|
-- Because this works well for roads that do not have relations as well
|
||||||
|
|
||||||
-- etldoc: osm_highway_linestring -> osm_transportation_name_linestring
|
-- etldoc: osm_highway_linestring -> osm_transportation_name_linestring
|
||||||
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS (
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
|
||||||
SELECT
|
SELECT
|
||||||
(ST_Dump(geometry)).geom AS geometry,
|
(ST_Dump(geometry)).geom AS geometry,
|
||||||
-- NOTE: The osm_id is no longer the original one which can make it difficult
|
-- NOTE: The osm_id is no longer the original one which can make it difficult
|
||||||
@ -35,11 +30,10 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS (
|
|||||||
GROUP BY name, highway, ref
|
GROUP BY name, highway, ref
|
||||||
) AS highway_union
|
) AS highway_union
|
||||||
);
|
);
|
||||||
|
|
||||||
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_geometry_idx ON osm_transportation_name_linestring USING gist(geometry);
|
||||||
|
|
||||||
-- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1
|
-- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1
|
||||||
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS (
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS (
|
||||||
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
||||||
FROM osm_transportation_name_linestring
|
FROM osm_transportation_name_linestring
|
||||||
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000
|
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000
|
||||||
@ -47,7 +41,7 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS (
|
|||||||
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_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist(geometry);
|
||||||
|
|
||||||
-- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2
|
-- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2
|
||||||
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS (
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen2 AS (
|
||||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
||||||
FROM osm_transportation_name_linestring_gen1
|
FROM osm_transportation_name_linestring_gen1
|
||||||
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000
|
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000
|
||||||
@ -55,9 +49,34 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS (
|
|||||||
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_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist(geometry);
|
||||||
|
|
||||||
-- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3
|
-- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3
|
||||||
CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen3 AS (
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS (
|
||||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
||||||
FROM osm_transportation_name_linestring_gen2
|
FROM osm_transportation_name_linestring_gen2
|
||||||
WHERE highway = 'motorway' AND ST_Length(geometry) > 20000
|
WHERE highway = 'motorway' AND ST_Length(geometry) > 20000
|
||||||
);
|
);
|
||||||
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_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry);
|
||||||
|
|
||||||
|
--- Triggers
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION refresh_osm_transportation_name_linestring() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring CONCURRENTLY;
|
||||||
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen1 CONCURRENTLY;
|
||||||
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen2 CONCURRENTLY;
|
||||||
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen3 CONCURRENTLY;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_refresh_osm_transportation_name_linestring
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE refresh_osm_transportation_name_linestring
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|||||||
@ -1,9 +1,7 @@
|
|||||||
|
|
||||||
DROP TABLE IF EXISTS osm_water_lakeline CASCADE;
|
|
||||||
|
|
||||||
-- etldoc: osm_water_polygon -> osm_water_lakeline
|
-- etldoc: osm_water_polygon -> osm_water_lakeline
|
||||||
-- etldoc: lake_centerline -> osm_water_lakeline
|
-- etldoc: lake_centerline -> osm_water_lakeline
|
||||||
CREATE TABLE IF NOT EXISTS osm_water_lakeline AS (
|
CREATE MATERIALIZED VIEW osm_water_lakeline AS (
|
||||||
SELECT wp.osm_id,
|
SELECT wp.osm_id,
|
||||||
ll.wkb_geometry AS geometry,
|
ll.wkb_geometry AS geometry,
|
||||||
name, name_en, ST_Area(wp.geometry) AS area
|
name, name_en, ST_Area(wp.geometry) AS area
|
||||||
@ -11,5 +9,20 @@ CREATE TABLE IF NOT EXISTS osm_water_lakeline AS (
|
|||||||
INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
|
INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
|
||||||
WHERE wp.name <> ''
|
WHERE wp.name <> ''
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS osm_water_lakeline_geometry_idx ON osm_water_lakeline USING gist(geometry);
|
CREATE INDEX IF NOT EXISTS osm_water_lakeline_geometry_idx ON osm_water_lakeline USING gist(geometry);
|
||||||
|
|
||||||
|
-- Triggers
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION refresh_osm_water_lakeline() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
REFRESH MATERIALIZED VIEW osm_water_lakeline CONCURRENTLY;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_refresh_osm_water_lakeline
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE refresh_osm_water_lakeline
|
||||||
|
|||||||
@ -1,9 +1,7 @@
|
|||||||
|
|
||||||
DROP TABLE IF EXISTS osm_water_point CASCADE;
|
|
||||||
|
|
||||||
-- etldoc: osm_water_polygon -> osm_water_point
|
-- etldoc: osm_water_polygon -> osm_water_point
|
||||||
-- etldoc: lake_centerline -> osm_water_point
|
-- etldoc: lake_centerline -> osm_water_point
|
||||||
CREATE TABLE IF NOT EXISTS osm_water_point AS (
|
CREATE MATERIALIZED VIEW osm_water_point AS (
|
||||||
SELECT
|
SELECT
|
||||||
wp.osm_id, topoint(wp.geometry) AS geometry,
|
wp.osm_id, topoint(wp.geometry) AS geometry,
|
||||||
wp.name, wp.name_en, ST_Area(wp.geometry) AS area
|
wp.name, wp.name_en, ST_Area(wp.geometry) AS area
|
||||||
@ -11,5 +9,20 @@ CREATE TABLE IF NOT EXISTS osm_water_point AS (
|
|||||||
LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
|
LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id
|
||||||
WHERE ll.osm_id IS NULL AND wp.name <> ''
|
WHERE ll.osm_id IS NULL AND wp.name <> ''
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry);
|
CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry);
|
||||||
|
|
||||||
|
-- Triggers
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION refresh_osm_water_point() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
REFRESH MATERIALIZED VIEW osm_water_point CONCURRENTLY;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_refresh_osm_water_point
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE refresh_osm_water_point
|
||||||
|
|||||||
@ -1,15 +1,10 @@
|
|||||||
|
|
||||||
DROP TABLE IF EXISTS osm_important_waterway_linestring CASCADE;
|
|
||||||
DROP TABLE IF EXISTS osm_important_waterway_linestring_gen1 CASCADE;
|
|
||||||
DROP TABLE IF EXISTS osm_important_waterway_linestring_gen2 CASCADE;
|
|
||||||
DROP TABLE IF EXISTS osm_important_waterway_linestring_gen3 CASCADE;
|
|
||||||
|
|
||||||
-- We merge the waterways by name like the highways
|
-- We merge the waterways by name like the highways
|
||||||
-- This helps to drop not important rivers (since they do not have a name)
|
-- This helps to drop not important rivers (since they do not have a name)
|
||||||
-- and also makes it possible to filter out too short rivers
|
-- and also makes it possible to filter out too short rivers
|
||||||
|
|
||||||
-- etldoc: osm_waterway_linestring -> osm_important_waterway_linestring
|
-- etldoc: osm_waterway_linestring -> osm_important_waterway_linestring
|
||||||
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring AS (
|
CREATE MATERIALIZED VIEW osm_important_waterway_linestring AS (
|
||||||
SELECT
|
SELECT
|
||||||
(ST_Dump(geometry)).geom AS geometry,
|
(ST_Dump(geometry)).geom AS geometry,
|
||||||
name
|
name
|
||||||
@ -22,11 +17,10 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring AS (
|
|||||||
GROUP BY name
|
GROUP BY name
|
||||||
) AS waterway_union
|
) AS waterway_union
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_geometry_idx ON osm_important_waterway_linestring USING gist(geometry);
|
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_geometry_idx ON osm_important_waterway_linestring USING gist(geometry);
|
||||||
|
|
||||||
-- etldoc: osm_important_waterway_linestring -> osm_important_waterway_linestring_gen1
|
-- etldoc: osm_important_waterway_linestring -> osm_important_waterway_linestring_gen1
|
||||||
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS (
|
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen1 AS (
|
||||||
SELECT ST_Simplify(geometry, 60) AS geometry, name
|
SELECT ST_Simplify(geometry, 60) AS geometry, name
|
||||||
FROM osm_important_waterway_linestring
|
FROM osm_important_waterway_linestring
|
||||||
WHERE ST_Length(geometry) > 1000
|
WHERE ST_Length(geometry) > 1000
|
||||||
@ -34,7 +28,7 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS (
|
|||||||
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen1_geometry_idx ON osm_important_waterway_linestring_gen1 USING gist(geometry);
|
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen1_geometry_idx ON osm_important_waterway_linestring_gen1 USING gist(geometry);
|
||||||
|
|
||||||
-- etldoc: osm_important_waterway_linestring_gen1 -> osm_important_waterway_linestring_gen2
|
-- etldoc: osm_important_waterway_linestring_gen1 -> osm_important_waterway_linestring_gen2
|
||||||
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS (
|
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen2 AS (
|
||||||
SELECT ST_Simplify(geometry, 100) AS geometry, name
|
SELECT ST_Simplify(geometry, 100) AS geometry, name
|
||||||
FROM osm_important_waterway_linestring_gen1
|
FROM osm_important_waterway_linestring_gen1
|
||||||
WHERE ST_Length(geometry) > 4000
|
WHERE ST_Length(geometry) > 4000
|
||||||
@ -42,9 +36,32 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS (
|
|||||||
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen2_geometry_idx ON osm_important_waterway_linestring_gen2 USING gist(geometry);
|
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen2_geometry_idx ON osm_important_waterway_linestring_gen2 USING gist(geometry);
|
||||||
|
|
||||||
-- etldoc: osm_important_waterway_linestring_gen2 -> osm_important_waterway_linestring_gen3
|
-- etldoc: osm_important_waterway_linestring_gen2 -> osm_important_waterway_linestring_gen3
|
||||||
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen3 AS (
|
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen3 AS (
|
||||||
SELECT ST_Simplify(geometry, 200) AS geometry, name
|
SELECT ST_Simplify(geometry, 200) AS geometry, name
|
||||||
FROM osm_important_waterway_linestring_gen2
|
FROM osm_important_waterway_linestring_gen2
|
||||||
WHERE ST_Length(geometry) > 8000
|
WHERE ST_Length(geometry) > 8000
|
||||||
);
|
);
|
||||||
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_geometry_idx ON osm_important_waterway_linestring_gen3 USING gist(geometry);
|
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_geometry_idx ON osm_important_waterway_linestring_gen3 USING gist(geometry);
|
||||||
|
|
||||||
|
--- Triggers
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION refresh_osm_important_waterway_linestring() RETURNS trigger AS
|
||||||
|
$BODY$
|
||||||
|
BEGIN
|
||||||
|
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring CONCURRENTLY;
|
||||||
|
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen1 CONCURRENTLY;
|
||||||
|
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen2 CONCURRENTLY;
|
||||||
|
REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen3 CONCURRENTLY;
|
||||||
|
RETURN null;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
language plpgsql
|
||||||
|
|
||||||
|
CREATE TRIGGER trigger_refresh_osm_important_waterway_linestring
|
||||||
|
AFTER INSERT OR UPDATE OR DELETE ON osm_waterway_linestring
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE refresh_osm_important_waterway_linestring
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user