Update Performance transportation_name Layer (#1512)
Improved update performance of transportation_name layer - Refactored LineString-merging and diff updates in update_transportation_name.sql - Refactored transportation_route_member_coalesced materialized view to table - Added analyze statements before update queries during transportation_name.refresh_network and update_osm_route_member
This commit is contained in:
parent
8321574565
commit
b2a57b3755
Binary file not shown.
|
Before Width: | Height: | Size: 865 KiB After Width: | Height: | Size: 772 KiB |
@ -32,15 +32,3 @@ $$
|
|||||||
'us-interstate');
|
'us-interstate');
|
||||||
$$ LANGUAGE sql IMMUTABLE
|
$$ LANGUAGE sql IMMUTABLE
|
||||||
PARALLEL SAFE;
|
PARALLEL SAFE;
|
||||||
|
|
||||||
DO
|
|
||||||
$$
|
|
||||||
BEGIN
|
|
||||||
BEGIN
|
|
||||||
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;
|
|
||||||
$$;
|
|
||||||
|
|||||||
@ -1,3 +1,5 @@
|
|||||||
|
DROP TRIGGER IF EXISTS trigger_store_transportation_highway_linestring ON osm_highway_linestring;
|
||||||
|
|
||||||
-- Create bounding windows for country-specific processing
|
-- Create bounding windows for country-specific processing
|
||||||
|
|
||||||
-- etldoc: ne_10m_admin_0_countries -> ne_10m_admin_0_gb_buffer
|
-- etldoc: ne_10m_admin_0_countries -> ne_10m_admin_0_gb_buffer
|
||||||
@ -16,9 +18,8 @@ WHERE iso_a2 = 'IE';
|
|||||||
-- etldoc: osm_highway_linestring -> gbr_route_members_view
|
-- etldoc: osm_highway_linestring -> gbr_route_members_view
|
||||||
-- etldoc: ne_10m_admin_0_gb_buffer -> gbr_route_members_view
|
-- etldoc: ne_10m_admin_0_gb_buffer -> gbr_route_members_view
|
||||||
CREATE OR REPLACE VIEW gbr_route_members_view AS
|
CREATE OR REPLACE VIEW gbr_route_members_view AS
|
||||||
SELECT 0,
|
SELECT osm_id AS member,
|
||||||
osm_id,
|
substring(ref FROM E'^[ABM][0-9ABM()]+') AS ref,
|
||||||
substring(ref FROM E'^[ABM][0-9ABM()]+'),
|
|
||||||
-- See https://wiki.openstreetmap.org/wiki/Roads_in_the_United_Kingdom
|
-- See https://wiki.openstreetmap.org/wiki/Roads_in_the_United_Kingdom
|
||||||
CASE WHEN highway = 'motorway' THEN 'omt-gb-motorway'
|
CASE WHEN highway = 'motorway' THEN 'omt-gb-motorway'
|
||||||
WHEN highway = 'trunk' THEN 'omt-gb-trunk'
|
WHEN highway = 'trunk' THEN 'omt-gb-trunk'
|
||||||
@ -32,9 +33,8 @@ WHERE length(ref) > 1
|
|||||||
-- etldoc: osm_highway_linestring -> ire_route_members_view
|
-- etldoc: osm_highway_linestring -> ire_route_members_view
|
||||||
-- etldoc: ne_10m_admin_0_ie_buffer -> ire_route_members_view
|
-- etldoc: ne_10m_admin_0_ie_buffer -> ire_route_members_view
|
||||||
CREATE OR REPLACE VIEW ire_route_members_view AS
|
CREATE OR REPLACE VIEW ire_route_members_view AS
|
||||||
SELECT 0,
|
SELECT osm_id AS member,
|
||||||
osm_id,
|
substring(ref FROM E'^[MNRL][0-9]+') AS ref,
|
||||||
substring(ref FROM E'^[MNRL][0-9]+'),
|
|
||||||
-- See https://wiki.openstreetmap.org/wiki/Ireland/Roads
|
-- See https://wiki.openstreetmap.org/wiki/Ireland/Roads
|
||||||
CASE WHEN highway = 'motorway' THEN 'omt-ie-motorway'
|
CASE WHEN highway = 'motorway' THEN 'omt-ie-motorway'
|
||||||
WHEN highway IN ('trunk','primary') THEN 'omt-ie-national'
|
WHEN highway IN ('trunk','primary') THEN 'omt-ie-national'
|
||||||
@ -45,23 +45,6 @@ WHERE length(ref) > 1
|
|||||||
AND highway IN ('motorway', 'trunk', 'primary', 'secondary', 'unclassified')
|
AND highway IN ('motorway', 'trunk', 'primary', 'secondary', 'unclassified')
|
||||||
;
|
;
|
||||||
|
|
||||||
-- Create GBR/IRE relations (so we can use it in the same way as other relations)
|
|
||||||
-- etldoc: osm_route_member -> osm_route_member
|
|
||||||
DELETE
|
|
||||||
FROM osm_route_member
|
|
||||||
WHERE network IN ('omt-gb-motorway', 'omt-gb-trunk', 'omt-gb-primary',
|
|
||||||
'omt-ie-motorway', 'omt-ie-national', 'omt-ie-national');
|
|
||||||
|
|
||||||
-- etldoc: gbr_route_members_view -> osm_route_member
|
|
||||||
INSERT INTO osm_route_member (osm_id, member, ref, network)
|
|
||||||
SELECT *
|
|
||||||
FROM gbr_route_members_view;
|
|
||||||
|
|
||||||
-- etldoc: ire_route_members_view -> osm_route_member
|
|
||||||
INSERT INTO osm_route_member (osm_id, member, ref, network)
|
|
||||||
SELECT *
|
|
||||||
FROM ire_route_members_view;
|
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION osm_route_member_network_type(network text, ref text) RETURNS route_network_type AS
|
CREATE OR REPLACE FUNCTION osm_route_member_network_type(network text, ref text) RETURNS route_network_type AS
|
||||||
$$
|
$$
|
||||||
SELECT CASE
|
SELECT CASE
|
||||||
@ -91,79 +74,132 @@ SELECT CASE
|
|||||||
$$ LANGUAGE sql IMMUTABLE
|
$$ LANGUAGE sql IMMUTABLE
|
||||||
PARALLEL SAFE;
|
PARALLEL SAFE;
|
||||||
|
|
||||||
-- etldoc: osm_route_member -> osm_route_member
|
CREATE TABLE IF NOT EXISTS transportation_route_member_coalesced
|
||||||
-- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes
|
(
|
||||||
UPDATE osm_route_member
|
member bigint,
|
||||||
SET network_type = osm_route_member_network_type(network, ref)
|
network varchar,
|
||||||
WHERE network != ''
|
ref varchar,
|
||||||
AND network_type IS DISTINCT FROM osm_route_member_network_type(network, ref)
|
osm_id bigint not null,
|
||||||
;
|
role varchar,
|
||||||
|
type smallint,
|
||||||
|
name varchar,
|
||||||
|
osmc_symbol varchar,
|
||||||
|
colour varchar,
|
||||||
|
network_type route_network_type,
|
||||||
|
concurrency_index integer,
|
||||||
|
rank integer,
|
||||||
|
PRIMARY KEY (member, network, ref)
|
||||||
|
);
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION update_osm_route_member() RETURNS void AS
|
CREATE OR REPLACE FUNCTION update_osm_route_member(full_update bool) RETURNS void AS
|
||||||
$$
|
$$
|
||||||
BEGIN
|
BEGIN
|
||||||
|
-- Analyze tracking and source tables before performing update
|
||||||
|
ANALYZE transportation_name.network_changes;
|
||||||
|
ANALYZE osm_highway_linestring;
|
||||||
|
ANALYZE osm_route_member;
|
||||||
|
|
||||||
DELETE
|
DELETE
|
||||||
FROM osm_route_member AS r
|
FROM transportation_route_member_coalesced
|
||||||
USING
|
USING transportation_name.network_changes c
|
||||||
transportation_name.network_changes AS c
|
WHERE c.is_old IS TRUE AND transportation_route_member_coalesced.member = c.osm_id;
|
||||||
WHERE network IN ('omt-gb-motorway', 'omt-gb-trunk', 'omt-gb-primary',
|
|
||||||
'omt-ie-motorway', 'omt-ie-national', 'omt-ie-regional')
|
|
||||||
AND r.osm_id = c.osm_id;
|
|
||||||
|
|
||||||
INSERT INTO osm_route_member (osm_id, member, ref, network)
|
-- Create GBR/IRE relations (so we can use it in the same way as other relations)
|
||||||
SELECT r.*
|
-- etldoc: gbr_route_members_view -> transportation_route_member_coalesced
|
||||||
FROM gbr_route_members_view AS r
|
INSERT INTO transportation_route_member_coalesced (member, network, ref, network_type, concurrency_index, osm_id)
|
||||||
JOIN transportation_name.network_changes AS c ON
|
SELECT member, network, ref, osm_route_member_network_type(network, ref) AS network_type,
|
||||||
r.osm_id = c.osm_id;
|
1 AS concurrency_index, 0 AS osm_id
|
||||||
|
FROM gbr_route_members_view
|
||||||
|
WHERE full_update OR EXISTS(
|
||||||
|
SELECT NULL
|
||||||
|
FROM transportation_name.network_changes c
|
||||||
|
WHERE c.is_old IS FALSE AND c.osm_id = gbr_route_members_view.member
|
||||||
|
)
|
||||||
|
GROUP BY member, network, ref
|
||||||
|
ON CONFLICT (member, network, ref) DO NOTHING;
|
||||||
|
|
||||||
INSERT INTO osm_route_member (osm_id, member, ref, network)
|
-- etldoc: ire_route_members_view -> transportation_route_member_coalesced
|
||||||
SELECT r.*
|
INSERT INTO transportation_route_member_coalesced (member, network, ref, network_type, concurrency_index, osm_id)
|
||||||
FROM ire_route_members_view AS r
|
SELECT member, network, ref, osm_route_member_network_type(network, ref) AS network_type,
|
||||||
JOIN transportation_name.network_changes AS c ON
|
1 AS concurrency_index, 0 AS osm_id
|
||||||
r.osm_id = c.osm_id;
|
FROM ire_route_members_view
|
||||||
|
WHERE full_update OR EXISTS(
|
||||||
|
SELECT NULL
|
||||||
|
FROM transportation_name.network_changes c
|
||||||
|
WHERE c.is_old IS FALSE AND c.osm_id = ire_route_members_view.member
|
||||||
|
)
|
||||||
|
GROUP BY member, network, ref
|
||||||
|
ON CONFLICT (member, network, ref) DO NOTHING;
|
||||||
|
|
||||||
INSERT INTO osm_route_member (id, osm_id, network_type)
|
-- etldoc: osm_route_member -> transportation_route_member_coalesced
|
||||||
|
INSERT INTO transportation_route_member_coalesced
|
||||||
SELECT
|
SELECT
|
||||||
id,
|
osm_route_member_filtered.*,
|
||||||
osm_id,
|
osm_route_member_network_type(network, ref) AS network_type,
|
||||||
osm_route_member_network_type(network, ref) AS network_type
|
DENSE_RANK() OVER (
|
||||||
FROM osm_route_member rm
|
PARTITION BY member
|
||||||
WHERE rm.member IN
|
ORDER BY osm_route_member_network_type(network, ref), network, LENGTH(ref), ref
|
||||||
(SELECT DISTINCT osm_id FROM transportation_name.network_changes)
|
) AS concurrency_index,
|
||||||
ON CONFLICT (id, osm_id) DO UPDATE SET network_type = EXCLUDED.network_type;
|
|
||||||
REFRESH MATERIALIZED VIEW transportation_route_member_coalesced;
|
|
||||||
END;
|
|
||||||
$$ LANGUAGE plpgsql;
|
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS osm_route_member_osm_id_idx ON osm_route_member ("osm_id");
|
|
||||||
|
|
||||||
-- etldoc: osm_route_member -> transportation_route_member_coalesced
|
|
||||||
DROP MATERIALIZED VIEW IF EXISTS transportation_route_member_coalesced CASCADE;
|
|
||||||
CREATE MATERIALIZED VIEW transportation_route_member_coalesced AS
|
|
||||||
SELECT
|
|
||||||
member,
|
|
||||||
network_type,
|
|
||||||
network,
|
|
||||||
ref,
|
|
||||||
DENSE_RANK() over (PARTITION BY member ORDER BY network_type, network, LENGTH(ref), ref) AS concurrency_index,
|
|
||||||
rank
|
|
||||||
FROM (
|
|
||||||
SELECT DISTINCT
|
|
||||||
member,
|
|
||||||
network_type,
|
|
||||||
network,
|
|
||||||
ref,
|
|
||||||
CASE
|
CASE
|
||||||
WHEN network IN ('iwn', 'nwn', 'rwn') THEN 1
|
WHEN network IN ('iwn', 'nwn', 'rwn') THEN 1
|
||||||
WHEN network = 'lwn' THEN 2
|
WHEN network = 'lwn' THEN 2
|
||||||
WHEN osmc_symbol || colour <> '' THEN 2
|
WHEN osmc_symbol || colour <> '' THEN 2
|
||||||
END AS rank
|
END AS rank
|
||||||
|
FROM (
|
||||||
|
-- etldoc: osm_route_member -> osm_route_member
|
||||||
|
-- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes
|
||||||
|
SELECT DISTINCT ON (member, network, ref)
|
||||||
|
member,
|
||||||
|
network,
|
||||||
|
ref,
|
||||||
|
osm_id,
|
||||||
|
role,
|
||||||
|
type,
|
||||||
|
name,
|
||||||
|
osmc_symbol,
|
||||||
|
colour
|
||||||
FROM osm_route_member
|
FROM osm_route_member
|
||||||
) osm_route_member_filtered
|
WHERE full_update OR EXISTS(
|
||||||
GROUP BY member, network_type, network, ref, rank;
|
SELECT NULL
|
||||||
|
FROM transportation_name.network_changes c
|
||||||
|
WHERE c.is_old IS FALSE AND c.osm_id = osm_route_member.member
|
||||||
|
)
|
||||||
|
) osm_route_member_filtered
|
||||||
|
ON CONFLICT (member, network, ref) DO UPDATE SET osm_id = EXCLUDED.osm_id, role = EXCLUDED.role,
|
||||||
|
type = EXCLUDED.type, name = EXCLUDED.name,
|
||||||
|
osmc_symbol = EXCLUDED.osmc_symbol, colour = EXCLUDED.colour,
|
||||||
|
rank = EXCLUDED.rank;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS transportation_route_member_member_idx ON transportation_route_member_coalesced ("member");
|
-- Indexes which can be utilized during full-update for queries originating from update_osm_route_member() function
|
||||||
CREATE INDEX IF NOT EXISTS osm_highway_linestring_osm_id_idx ON osm_highway_linestring ("osm_id");
|
CREATE INDEX IF NOT EXISTS osm_route_member_member_network_ref_idx ON osm_route_member (member, network, ref);
|
||||||
|
|
||||||
|
-- Analyze created index
|
||||||
|
ANALYZE osm_route_member;
|
||||||
|
|
||||||
|
-- Ensure transportation_name.network_changes table exists since it is required by update_osm_route_member
|
||||||
|
CREATE SCHEMA IF NOT EXISTS transportation_name;
|
||||||
|
CREATE TABLE IF NOT EXISTS transportation_name.network_changes
|
||||||
|
(
|
||||||
|
is_old bool,
|
||||||
|
osm_id bigint,
|
||||||
|
PRIMARY KEY (is_old, osm_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Fill transportation_route_member_coalesced table
|
||||||
|
TRUNCATE transportation_route_member_coalesced;
|
||||||
|
SELECT update_osm_route_member(TRUE);
|
||||||
|
|
||||||
|
-- Index for queries against transportation_route_member_coalesced during transportation-name-network updates
|
||||||
|
CREATE INDEX IF NOT EXISTS transportation_route_member_member_idx ON
|
||||||
|
transportation_route_member_coalesced ("member", "concurrency_index");
|
||||||
|
|
||||||
|
-- Analyze populated table with indexes
|
||||||
|
ANALYZE transportation_route_member_coalesced;
|
||||||
|
|
||||||
|
-- Ensure OSM-ID index exists on osm_highway_linestring
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS osm_highway_linestring_osm_id_idx ON osm_highway_linestring ("osm_id");
|
||||||
|
|
||||||
-- etldoc: osm_route_member -> osm_highway_linestring
|
-- etldoc: osm_route_member -> osm_highway_linestring
|
||||||
UPDATE osm_highway_linestring hl
|
UPDATE osm_highway_linestring hl
|
||||||
|
|||||||
@ -54,7 +54,20 @@ SELECT geometry,
|
|||||||
FROM (
|
FROM (
|
||||||
|
|
||||||
-- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6
|
-- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6
|
||||||
SELECT *,
|
SELECT geometry,
|
||||||
|
tags,
|
||||||
|
ref,
|
||||||
|
highway,
|
||||||
|
subclass,
|
||||||
|
brunnel,
|
||||||
|
network,
|
||||||
|
route_1,
|
||||||
|
route_2,
|
||||||
|
route_3,
|
||||||
|
route_4,
|
||||||
|
route_5,
|
||||||
|
route_6,
|
||||||
|
z_order,
|
||||||
NULL::int AS layer,
|
NULL::int AS layer,
|
||||||
NULL::int AS level,
|
NULL::int AS level,
|
||||||
NULL::boolean AS indoor
|
NULL::boolean AS indoor
|
||||||
@ -63,7 +76,20 @@ FROM (
|
|||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
-- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7
|
-- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7
|
||||||
SELECT *,
|
SELECT geometry,
|
||||||
|
tags,
|
||||||
|
ref,
|
||||||
|
highway,
|
||||||
|
subclass,
|
||||||
|
brunnel,
|
||||||
|
network,
|
||||||
|
route_1,
|
||||||
|
route_2,
|
||||||
|
route_3,
|
||||||
|
route_4,
|
||||||
|
route_5,
|
||||||
|
route_6,
|
||||||
|
z_order,
|
||||||
NULL::int AS layer,
|
NULL::int AS layer,
|
||||||
NULL::int AS level,
|
NULL::int AS level,
|
||||||
NULL::boolean AS indoor
|
NULL::boolean AS indoor
|
||||||
@ -72,7 +98,20 @@ FROM (
|
|||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
-- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8
|
-- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8
|
||||||
SELECT *,
|
SELECT geometry,
|
||||||
|
tags,
|
||||||
|
ref,
|
||||||
|
highway,
|
||||||
|
subclass,
|
||||||
|
brunnel,
|
||||||
|
network,
|
||||||
|
route_1,
|
||||||
|
route_2,
|
||||||
|
route_3,
|
||||||
|
route_4,
|
||||||
|
route_5,
|
||||||
|
route_6,
|
||||||
|
z_order,
|
||||||
NULL::int AS layer,
|
NULL::int AS layer,
|
||||||
NULL::int AS level,
|
NULL::int AS level,
|
||||||
NULL::boolean AS indoor
|
NULL::boolean AS indoor
|
||||||
@ -83,7 +122,20 @@ FROM (
|
|||||||
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z9
|
-- 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:z10
|
||||||
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11
|
-- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11
|
||||||
SELECT *,
|
SELECT geometry,
|
||||||
|
tags,
|
||||||
|
ref,
|
||||||
|
highway,
|
||||||
|
subclass,
|
||||||
|
brunnel,
|
||||||
|
network,
|
||||||
|
route_1,
|
||||||
|
route_2,
|
||||||
|
route_3,
|
||||||
|
route_4,
|
||||||
|
route_5,
|
||||||
|
route_6,
|
||||||
|
z_order,
|
||||||
NULL::int AS layer,
|
NULL::int AS layer,
|
||||||
NULL::int AS level,
|
NULL::int AS level,
|
||||||
NULL::boolean AS indoor
|
NULL::boolean AS indoor
|
||||||
|
|||||||
File diff suppressed because it is too large
Load Diff
Loading…
x
Reference in New Issue
Block a user