Move where condition from osm_transportation_name_linestring to materialized view osm_transportation_name_network (#991)
Reduce the size of the materialized view osm_transportation_name_network by moving the weare clause. osm_transportation_name_network is only used for osm_transportation_name_linestring. Co-authored-by: zstadler <zeev.stadler@gmail.com>
This commit is contained in:
parent
550b1f8f90
commit
5c640daf4f
@ -7,30 +7,49 @@
|
||||
-- etldoc: osm_highway_linestring -> osm_transportation_name_network
|
||||
-- etldoc: osm_route_member -> osm_transportation_name_network
|
||||
CREATE TABLE IF NOT EXISTS 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
|
||||
;
|
||||
SELECT
|
||||
geometry,
|
||||
osm_id,
|
||||
name,
|
||||
name_en,
|
||||
name_de,
|
||||
tags,
|
||||
ref,
|
||||
highway,
|
||||
construction,
|
||||
"level",
|
||||
layer,
|
||||
indoor,
|
||||
network_type,
|
||||
z_order
|
||||
FROM (
|
||||
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
|
||||
WHERE (hl.name <> '' OR hl.ref <> '')
|
||||
AND NULLIF(hl.highway, '') IS NOT NULL
|
||||
) AS t
|
||||
WHERE ("rank" = 1 OR "rank" IS NULL);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_osm_id_idx ON osm_transportation_name_network (osm_id);
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist (geometry);
|
||||
|
||||
@ -69,9 +88,6 @@ FROM (
|
||||
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 */;
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user