From 4c824531a234add0143d2f0780bd49d1da3b9dbb Mon Sep 17 00:00:00 2001 From: afischerdev Date: Tue, 27 May 2025 11:45:23 +0200 Subject: [PATCH] db scripts pushed to last state --- misc/scripts/mapcreation/brouter.sql | 1937 ++++++++++++++-------- misc/scripts/mapcreation/brouter_cfg.lua | 8 +- 2 files changed, 1217 insertions(+), 728 deletions(-) diff --git a/misc/scripts/mapcreation/brouter.sql b/misc/scripts/mapcreation/brouter.sql index 359f093..4e8a7a9 100644 --- a/misc/scripts/mapcreation/brouter.sql +++ b/misc/scripts/mapcreation/brouter.sql @@ -2,6 +2,845 @@ -- formatted by https://sqlformat.darold.net/ SET client_encoding TO UTF8; +-- prepare the lines table with a new index and a new column +SELECT + now(); + +ANALYZE; + +SELECT + now(); + +SELECT + osm_id, + highway, + maxspeed, + way, + waterway, + li.natural, + width, + oneway, + st_length (way) / st_length (ST_Transform (way, 4326)::geography) AS merca_coef INTO TABLE lines_bis +FROM + lines li; + +SELECT + now(); + +DROP TABLE lines; + +ALTER TABLE lines_bis RENAME TO lines; + +CREATE INDEX lines_osm_id_idx ON lines (osm_id) WITH (fillfactor = '100'); + +CREATE INDEX lines_way_idx ON public.lines USING gist (way) WITH (fillfactor = '100'); + +ANALYZE lines; + +-- generation of pseudo-tags +-- 1: noise +-- create a table with the segments producing noise (motorway, primary and secondary) and a noise_factor for each. +-- the noise_factor depends on the highway type, maxspeed and oneway +-- oneway is basically given on motorway segments, in some cases also on primary... +-- then 2 segments exist on the same route, so noise_factor per segment is lower!!!! +SELECT + now(); + +SELECT + osm_id::bigint, + highway, + maxspeed, + CASE WHEN maxspeed IS NULL + OR (NOT (maxspeed ~ '^\d+(\.\d+)?$')) + OR maxspeed::numeric > '105' THEN + -- maxspeed not defined OR not numeric / usable OR > 105 km/h + CASE WHEN highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link') THEN + 0.6 + WHEN highway IN ('primary', 'primary_link') THEN + CASE WHEN oneway IS NULL + OR oneway NOT IN ('yes', 'true', '1') THEN + 0.66 + ELSE + 0.45 + END + WHEN highway IN ('secondary') THEN + 0.33 + ELSE + 0 + END + WHEN maxspeed::numeric > '75' THEN + -- 75 < maxspeed <= 105 + CASE WHEN highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link') THEN + 0.55 + WHEN highway IN ('primary', 'primary_link') THEN + CASE WHEN oneway IS NULL + OR oneway NOT IN ('yes', 'true', '1') THEN + 0.66 + ELSE + 0.45 + END + WHEN highway IN ('secondary') THEN + 0.33 + ELSE + 0 + END + ELSE + -- maxspeed <= 75 + CASE WHEN highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link') THEN + 0.4 + WHEN highway IN ('primary', 'primary_link') THEN + CASE WHEN oneway IS NULL + OR oneway NOT IN ('yes', 'true', '1') THEN + 0.4 + ELSE + 0.3 + END + WHEN highway IN ('secondary') THEN + 0.2 + ELSE + 0 + END + END AS noise_factor, + way AS way, + ST_Buffer (way, 75 * merca_coef) AS way75, + merca_coef INTO TABLE noise_emittnew +FROM + lines li +WHERE + highway IS NOT NULL + AND highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link', 'primary', 'primary_link', 'secondary'); + +SELECT + now(); + +CREATE INDEX noise_emittnew_osm_id_idx ON noise_emittnew (osm_id) WITH (fillfactor = '100'); + +-- modify noise_factor by very small segments +SELECT + now(); + +UPDATE + noise_emittnew +SET + noise_factor = noise_factor * (st_length (way) / merca_coef) / 20 +WHERE (st_length (way) / merca_coef) < 20; + +SELECT + now(); + +ANALYZE noise_emittnew; + +SELECT + now(); + +-- create a tuple (highway + noise source) of the highways having noise (for perf tuning) +SELECT + dd.osm_id::bigint AS lines_osm_id, + dd.highway, + dd.merca_coef, + dd.way, + q.osm_id AS noise_osm_id INTO TABLE tuples_with_noise +FROM + lines dd + INNER JOIN noise_emittnew AS q ON ST_Intersects (dd.way, q.way75) +WHERE + dd.highway IS NOT NULL + AND dd.highway NOT IN ('proposed', 'construction') + AND (st_length (dd.way) / dd.merca_coef) < 40000; + +--group by dd.osm_id, dd.highway, dd.merca_coef, dd.way; +SELECT + now(); + +CREATE INDEX tuples_with_noise_osm_id_idx ON tuples_with_noise (lines_osm_id) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE tuples_with_noise; + +SELECT + lines_osm_id AS osm_id, + way, + merca_coef INTO TABLE lines_with_noise +FROM + tuples_with_noise +GROUP BY + lines_osm_id, + merca_coef, + way; + +SELECT + now(); + +CREATE INDEX lineswithnoise_osm_id_idx ON lines_with_noise (osm_id) WITH (fillfactor = '100'); + +ANALYZE lines_with_noise; + +-- calculate noise using "lines_with_noise" +-- split each segment with noise into 20 meter sections and calculate the noise per section +-- the average giving the noise for the segment +SELECT + now(); + +WITH lines_split AS ( + SELECT + osm_id, + merca_coef, + ST_LineSubstring (d.way, startfrac, LEAST (endfrac, 1)) AS way, + len / merca_coef AS lgt_seg_real + FROM ( + SELECT + osm_id, + merca_coef, + way, + st_length (way) len, + (20 * merca_coef) sublen + FROM + lines_with_noise) AS d + CROSS JOIN LATERAL ( + SELECT + i, + (sublen * i) / len AS startfrac, + (sublen * (i + 1)) / len AS endfrac + FROM + generate_series(0, floor(len / sublen)::integer) AS t (i) + -- skip last i if line length is exact multiple of sublen + WHERE (sublen * i) / len <> 1.0) AS d2 +) +SELECT + m.osm_id::bigint losmid, + m.lgt_seg_real, + st_distance (m.way, t.way) / m.merca_coef AS dist, + -- the line below delivers the same result as above !!!!!!! but need much more time (* 7 !) + -- st_distance(st_transform(m.way, 4326)::geography, st_transform(t.way, 4326)::geography) as distgeog, + t.noise_factor INTO TABLE noise_tmp2newz +FROM + lines_split AS m + INNER JOIN tuples_with_noise AS q ON m.osm_id = q.lines_osm_id + INNER JOIN noise_emittnew t ON t.osm_id = q.noise_osm_id +WHERE + st_distance (m.way, t.way) / m.merca_coef < 75; + +SELECT + now(); + +ANALYZE noise_tmp2newz; + +-- group +SELECT + now(); + +-- calculate an indicator per section (1 / d*d here) and reduce the results by taking the average on the osm_segment +SELECT + losmid, + m.lgt_seg_real, + sum(noise_factor / ((dist + 15) / 15)) / ((m.lgt_seg_real / 20)::integer + 1) AS sum_noise_factor INTO noise_tmp2new +FROM + noise_tmp2newz m +GROUP BY + m.losmid, + m.lgt_seg_real; + +SELECT + now(); + +DROP TABLE noise_tmp2newz; + +DROP TABLE tuples_with_noise; + +DROP TABLE noise_emittnew; + +ANALYZE noise_tmp2new; + +SELECT + now(); + +-- add noise from Airports... +-- polygons of the international airports +SELECT + name, + st_buffer (way, (700 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography))) AS way INTO TABLE poly_airportnew +FROM + polygons +WHERE + aeroway = 'aerodrome' + AND aerodrome = 'international'; + +SELECT + now(); + +ANALYZE poly_airportnew; + +SELECT + m.osm_id::bigint losmid, + -- st_area(st_intersection(m.way, q.way)) / (st_area(m.way) * 1.5) + -- 1 / 1.5 + (700 - (st_distance (m.way, q.way) / m.merca_coef)) / (700 * 1.5) AS dist_factor INTO TABLE noise_airportnew +FROM + lines AS m + INNER JOIN poly_airportnew AS q ON ST_intersects (m.way, q.way) +WHERE + m.highway IS NOT NULL +ORDER BY + dist_factor DESC; + +SELECT + now(); + +ANALYZE noise_airportnew; + +SELECT + losmid, + sum(noise_factor) AS sum_noise_factor INTO TABLE noise_tmp3new +FROM (( + SELECT + losmid, + sum_noise_factor AS noise_factor + FROM + noise_tmp2new AS nois1) + UNION ( + SELECT + losmid, + dist_factor AS noise_factor + FROM + noise_airportnew AS nois2)) AS nois_sum +GROUP BY + losmid; + +SELECT + now(); + +ANALYZE noise_tmp3new; + +-- create the noise classes +SELECT + now(); + +SELECT + losmid, + CASE WHEN y.sum_noise_factor < 0.06 THEN + '1' + WHEN y.sum_noise_factor < 0.13 THEN + '2' + WHEN y.sum_noise_factor < 0.26 THEN + '3' + WHEN y.sum_noise_factor < 0.45 THEN + '4' + WHEN y.sum_noise_factor < 0.85 THEN + '5' + ELSE + '6' + END AS noise_class INTO TABLE noise_tags +FROM + noise_tmp3new y +WHERE + y.sum_noise_factor > 0.01 +ORDER BY + noise_class; + +SELECT + now(); + +ANALYZE noise_tags; + +SELECT + count(*) +FROM + noise_tags; + +SELECT + noise_class, + count(*) +FROM + noise_tags +GROUP BY + noise_class +ORDER BY + noise_class; + +------------------------------------------------------------------------- +-- 2: create tags for river +-- create a table with the segments and polygons with "river" (or water!) +SELECT + now(); + +WITH river_from_polygons AS ( + SELECT + osm_id::bigint, + way, + ST_Buffer (way, 110 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography)) AS way2 + FROM + polygons q + WHERE + q.natural IN ('water', 'bay', 'beach', 'wetland') + AND (q.water IS NULL + OR q.water NOT IN ('wastewater')) + AND st_area (ST_Transform (q.way, 4326)::geography) BETWEEN 1000 AND 5000000000 +), +river_from_lines AS ( + SELECT + osm_id::bigint, + way, + ST_Buffer (way, 80 * merca_coef) AS way2 + FROM + lines q + WHERE + q.waterway IN ('river', 'canal', 'fairway') + OR q.natural IN ('coastline') + ORDER BY + way +), +river_coastline AS ( + SELECT + osm_id::bigint, + way, + ST_Buffer (ST_ExteriorRing (way), 100 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography)) AS way2 + FROM + polygons p + WHERE + st_area (ST_Transform (p.way, 4326)::geography) > 1000 + AND (p.natural IN ('coastline') + AND st_length (way) < 100000) + ORDER BY + way +) +SELECT + * INTO river_proxy +FROM ( + SELECT + * + FROM + river_from_polygons part1 + UNION + SELECT + * + FROM + river_from_lines part2 + UNION + SELECT + * + FROM + river_coastline part3) AS sumriver; + +SELECT + now(); + +CREATE INDEX river_proxy_osm_id_idx ON river_proxy (osm_id) WITH (fillfactor = '100'); + +ANALYZE river_proxy; + +SELECT + now(); + +-- create a tuple (highway + noise source) of the highways in river proxymity (for perf tuning) +SELECT + dd.osm_id::bigint AS lines_osm_id, + dd.merca_coef, + dd.way, + q.osm_id AS river_osm_id INTO TABLE tuples_with_river +FROM + lines dd + INNER JOIN river_proxy AS q ON ST_Intersects (dd.way, q.way2) +WHERE + dd.highway IS NOT NULL + AND dd.highway NOT IN ('proposed', 'construction') + AND (st_length (dd.way) / dd.merca_coef) < 40000; + +SELECT + now(); + +CREATE INDEX tuples_with_river_osm_id_idx ON tuples_with_river (lines_osm_id) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE tuples_with_river; + +SELECT + now(); + +-- create a table of highways with river... +SELECT + lines_osm_id AS osm_id, + way, + merca_coef INTO TABLE lines_with_river +FROM + tuples_with_river +GROUP BY + lines_osm_id, + merca_coef, + way; + +SELECT + now(); + +CREATE INDEX lineswithriver_osm_id_idx ON lines_with_river (osm_id) WITH (fillfactor = '100'); + +ANALYZE lines_with_river; + +SELECT + now(); + +-- calculate river factor using "lines_with_river" +-- split each segment with river into 20 meter sections and calculate the river per section +-- the average giving the river_factor for the segment +WITH lines_split AS ( + SELECT + osm_id, + merca_coef, + ST_LineSubstring (d.way, startfrac, LEAST (endfrac, 1)) AS way, + len / merca_coef AS lgt_seg_real + FROM ( + SELECT + osm_id, + merca_coef, + way, + st_length (way) len, + (20 * merca_coef) sublen + FROM + lines_with_river) AS d + CROSS JOIN LATERAL ( + SELECT + i, + (sublen * i) / len AS startfrac, + (sublen * (i + 1)) / len AS endfrac + FROM + generate_series(0, floor(len / sublen)::integer) AS t (i) + -- skip last i if line length is exact multiple of sublen + WHERE (sublen * i) / len <> 1.0) AS d2 +) +SELECT + m.osm_id::bigint losmid, + m.lgt_seg_real, + st_distance (m.way, t.way) / m.merca_coef AS dist INTO TABLE river_tmp2newz +FROM + lines_split AS m + INNER JOIN tuples_with_river AS q ON m.osm_id = q.lines_osm_id + INNER JOIN river_proxy t ON t.osm_id = q.river_osm_id +WHERE + st_distance (m.way, t.way) / m.merca_coef < 165; + +SELECT + now(); + +ANALYZE river_tmp2newz; + +SELECT + now(); + +SELECT + losmid, + m.lgt_seg_real, + sum(1 / ((dist + 50) / 50)) / ((m.lgt_seg_real / 20)::integer + 1) AS sum_river_factor INTO river_tmp2new +FROM + river_tmp2newz m +GROUP BY + m.losmid, + m.lgt_seg_real; + +SELECT + now(); + +DROP TABLE river_tmp2newz; + +DROP TABLE tuples_with_river; + +DROP TABLE river_proxy; + +ANALYZE river_tmp2new; + +SELECT + now(); + +SELECT + losmid, + CASE WHEN y.sum_river_factor < 0.22 THEN + '1' + WHEN y.sum_river_factor < 0.35 THEN + '2' + WHEN y.sum_river_factor < 0.5 THEN + '3' + WHEN y.sum_river_factor < 0.75 THEN + '4' + WHEN y.sum_river_factor < 0.98 THEN + '5' + ELSE + '6' + END AS river_class INTO TABLE river_tags +FROM + river_tmp2new y +WHERE + y.sum_river_factor > 0.03; + +SELECT + now(); + +SELECT + count(*) +FROM + river_tags; + +SELECT + river_class, + count(*) +FROM + river_tags +GROUP BY + river_class +ORDER BY + river_class; + +SELECT + now(); + +------------------------------------------------------------- +-- create pseudo-tags for forest +-- +-- create first a table of the polygons with forest +SELECT + now(); + +SELECT + osm_id::bigint, + leisure, + landuse, + p.natural, + p.water, + way, + ST_Buffer (way, 32.15 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography)) AS way32 INTO TABLE osm_poly_forest +FROM + polygons p +WHERE + st_area (ST_Transform (p.way, 4326)::geography) > 1500 + AND ((p.landuse IN ('forest', 'allotments', 'flowerbed', 'orchard', 'vineyard', 'recreation_ground', 'village_green')) + OR p.leisure IN ('garden', 'park', 'nature_reserve')) + AND st_area (ST_Transform (p.way, 4326)::geography) BETWEEN 5000 AND 5000000000 +ORDER BY + way; + +SELECT + now(); + +CREATE INDEX osm_poly_forest_osm_id_idx ON osm_poly_forest (osm_id) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE osm_poly_forest; + +-- create a table of the lines within forests (green_factor is nomally 1, but 5 is better to calculate class 6 ) +SELECT + now(); + +SELECT + m.osm_id::bigint, + m.highway, + 6 AS green_factor INTO TABLE lines_within_forest +FROM + lines AS m + INNER JOIN osm_poly_forest q ON ST_Within (m.way, q.way) +WHERE + m.highway IS NOT NULL +GROUP BY + m.osm_id, + m.highway, + m.way; + +CREATE INDEX lines_within_forest_osm_id_idx ON lines_within_forest (osm_id) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE lines_within_forest; + +-- create a tuple table (lines+polygons) of the lines near but not within forests +SELECT + m.osm_id::bigint AS lines_osm_id, + m.highway, + m.merca_coef, + m.way AS lines_way, + q.osm_id AS forest_osm_id INTO TABLE tuples_limit_forest +FROM + lines AS m + INNER JOIN osm_poly_forest AS q ON ST_Intersects (m.way, q.way32) +WHERE + m.highway IS NOT NULL + AND m.highway NOT IN ('proposed', 'construction') + AND (st_length (m.way) / m.merca_coef) < 40000 + AND m.osm_id::bigint NOT IN ( + SELECT + osm_id + FROM + lines_within_forest); + +SELECT + now(); + +CREATE INDEX tuples_lines_osm_id_idx ON tuples_limit_forest (lines_osm_id) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE tuples_limit_forest; + +SELECT + now(); + +-- create a table with only the lines near but not within forests +SELECT + m.lines_osm_id osm_id, + m.highway, + m.merca_coef, + m.lines_way AS way INTO TABLE lines_limit_forest +FROM + tuples_limit_forest AS m +GROUP BY + m.lines_osm_id, + m.highway, + m.merca_coef, + m.lines_way; + +SELECT + now(); + +CREATE INDEX lines_limit_forest_osm_id_idx ON lines_limit_forest (osm_id) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE lines_limit_forest; + +-- calculate the forest factor (or green_factor) for the lines at forest limit.. +-- spilt the line into 20 meter sections +-- calculate the distance section-forest +SELECT + now(); + +WITH lines_split AS ( + SELECT + osm_id, + highway, + merca_coef, + ST_LineSubstring (d.way, startfrac, LEAST (endfrac, 1)) AS way, + len / merca_coef AS lgt_seg_real + FROM ( + SELECT + osm_id, + highway, + merca_coef, + way, + st_length (way) len, + (20 * merca_coef) sublen + FROM + lines_limit_forest) AS d + CROSS JOIN LATERAL ( + SELECT + i, + (sublen * i) / len AS startfrac, + (sublen * (i + 1)) / len AS endfrac + FROM + generate_series(0, floor(len / sublen)::integer) AS t (i) + -- skip last i if line length is exact multiple of sublen + WHERE (sublen * i) / len <> 1.0) AS d2 +) +SELECT + m.osm_id, + lgt_seg_real, + st_distance (m.way, t.way) / m.merca_coef AS dist INTO TABLE forest_tmp2newz +FROM + lines_split AS m + INNER JOIN tuples_limit_forest AS q ON m.osm_id = q.lines_osm_id + INNER JOIN osm_poly_forest t ON t.osm_id = q.forest_osm_id +WHERE + st_distance (m.way, t.way) / m.merca_coef < 65; + +SELECT + now(); + +ANALYZE forest_tmp2newz; + +SELECT + now(); + +SELECT + m.osm_id, + m.lgt_seg_real, + sum(1 / ((dist + 25) / 25)) / ((m.lgt_seg_real / 20)::integer + 1) AS green_factor INTO forest_tmp2new +FROM + forest_tmp2newz m +GROUP BY + m.osm_id, + m.lgt_seg_real; + +SELECT + now(); + +ANALYZE forest_tmp2new; + +DROP TABLE forest_tmp2newz; + +DROP TABLE osm_poly_forest; + +DROP TABLE tuples_limit_forest; + +SELECT + now(); + +-- merge lines_within_forest with lines_limit_forest +WITH forest_tmp3new AS ( + SELECT + * + FROM ( + SELECT + osm_id, + green_factor + FROM + forest_tmp2new AS part1 + UNION + SELECT + osm_id, + green_factor + FROM + lines_within_forest) AS part2 +) +SELECT + y.osm_id losmid, + CASE WHEN y.green_factor < 0.32 THEN + '1' + WHEN y.green_factor < 0.5 THEN + '2' + WHEN y.green_factor < 0.7 THEN + '3' + WHEN y.green_factor < 0.92 THEN + '4' + WHEN y.green_factor < 5 THEN + '5' + ELSE + '6' + END AS forest_class INTO TABLE forest_tags +FROM + forest_tmp3new y +WHERE + y.green_factor > 0.1; + +ANALYZE forest_tags; + +SELECT + count(*) +FROM + forest_tags; + +SELECT + forest_class, + count(*) +FROM + forest_tags +GROUP BY + forest_class +ORDER BY + forest_class; + SELECT now(); @@ -21,133 +860,10 @@ $$ LANGUAGE plpgsql SECURITY INVOKER; --- create new tables for tuning --- -SELECT - osm_id::bigint, - highway, - waterway, - li.natural, - width, - maxspeed, - CASE WHEN maxspeed IS NULL THEN - 0 - --when not isnumeric(maxspeed) then 0 - WHEN NOT (maxspeed ~ '^\d+(\.\d+)?$') THEN - 0 - WHEN maxspeed::numeric > '105' THEN - 1 - WHEN maxspeed::numeric > '75' THEN - 2 - ELSE - 3 - END AS maxspeed_class - -- "buffer radius" was initially created with 50 meters at a latitude of 50 degrees... ==> ST_Buffer(way,50) - -- but, using geometry "projection", to get same results by a calculation of the planet (latitude between -80, +85) this value should be adapted to the latitude of the highways... -, - -- - ST_Buffer (way, 32.15 * st_length (ST_Transform (way, 3857)) / st_length (ST_Transform (way, 4326)::geography)) AS way INTO TABLE osm_line_buf_50 -FROM - lines li -WHERE - highway IS NOT NULL - OR waterway IN ('river', 'canal', 'fairway') - OR (li.natural = 'coastline' - AND st_length (way) < 100000); - SELECT now(); --- modify "way" by large waterways !!" (example Rhein ==> width = 400 ...) enlarge a bit the "50 meter" buffer -UPDATE - osm_line_buf_50 -SET - way = st_buffer (way, (width::numeric / 10)) -WHERE - waterway = 'river' - AND width IS NOT NULL - AND (width ~ '^[0-9\.]+$') - AND width::numeric > 15 - AND width::numeric < 2500; - -SELECT - osm_id::bigint, - leisure, - landuse, - p.natural, - p.water, - ST_Buffer (way, 32.15 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography)) AS way INTO TABLE osm_poly_buf_50 -FROM - polygons p -WHERE - -- do not consider small surfaces - st_area (p.way) > 1000 - AND (p.natural IN ('water', 'bay', 'beach', 'wetland') - OR p.landuse IN ('forest', 'allotments', 'flowerbed', 'orchard', 'vineyard', 'recreation_ground', 'village_green') - OR p.leisure IN ('garden', 'park', 'nature_reserve')); - --- by forest no buffer ! -SELECT - osm_id::bigint, - leisure, - landuse, - p.natural, - p.water, - way INTO TABLE osm_poly_no_buf -FROM - polygons p -WHERE - -- do not consider small surfaces - st_area (p.way) > 1000 - AND (p.natural IN ('water', 'bay', 'beach', 'costline', 'wetland') - OR p.landuse IN ('forest', 'allotments', 'flowerbed', 'orchard', 'vineyard', 'recreation_ground', 'village_green') - OR p.leisure IN ('garden', 'park', 'nature_reserve')); - -SELECT - osm_id::bigint, - leisure, - landuse, - p.natural, - p.water, - ST_Buffer (way, 45 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography)) AS way INTO TABLE osm_poly_buf_120 -FROM - osm_poly_buf_50 p; - --- for coastline special case -SELECT - osm_id::bigint, - leisure, - landuse, - p.natural, - p.water, - ST_Buffer (ST_ExteriorRing (way), 64 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography)) AS way INTO TABLE osm_poly_coastline_buf_100 -FROM - polygons p -WHERE - -- do not consider small surfaces - st_area (p.way) > 1000 - AND (p.natural IN ('coastline') - AND st_length (way) < 100000); - ---CREATE INDEX osm_poly_coastline_ind ON public.osm_poly_coastline_buf_100 USING gist (way) WITH (fillfactor='100'); -SELECT - * INTO TABLE osm_line_water -FROM - osm_line_buf_50 q -WHERE - q.waterway IN ('river', 'canal', 'fairway') - OR q.natural IN ('coastline'); - -CREATE INDEX osm_line_water_ind ON public.osm_line_water USING gist (way) WITH (fillfactor = '100'); - -SELECT - now(); - --- create indexes -CREATE INDEX osm_line_buf_50_idx ON public.osm_line_buf_50 USING gist (way) WITH (fillfactor = '100'); - -ANALYZE; - +-- create tables for traffic SELECT osm_id, highway, @@ -166,6 +882,168 @@ CREATE INDEX primsecter15k_idx1 ON public.primsecter15k USING gist (way) WITH (f CREATE INDEX primsecter15k_idx0 ON public.primsecter15k USING gist (way0) WITH (fillfactor = '100'); +ANALYZE primsecter15k; + +SELECT + now(); + +-- consistency check on population, first evaluate and documents it +WITH cities_x AS ( + SELECT + a.name, + a.name_en, + place, + osm_id, + replace(a.population, '.', '')::bigint population, + a.way + FROM + cities a + WHERE + a.population IS NOT NULL + AND isnumeric (a.population) + AND a.place IN ('village', 'town', 'city', 'municipality')) +SELECT + name, + name_en, + place, + population, + osm_id +FROM + cities_x a +WHERE (place = 'village' + AND a.population > 90000) + OR (place = 'town' + AND a.population > 1500000) + OR (place = 'city' + AND a.population > 40000000) +ORDER BY + place, + Population DESC; + +WITH cities_relx AS ( + SELECT + a.name, + a.name_en, + place, + osm_id, + replace(a.population, '.', '')::bigint population, + a.way + FROM + cities_rel a + WHERE + a.population IS NOT NULL + AND isnumeric (a.population) + AND a.place IN ('village', 'town', 'city', 'municipality')) +SELECT + name, + name_en, + place, + population, + osm_id +FROM + cities_relx a +WHERE (place = 'village' + AND a.population > 90000) + OR (place = 'town' + AND a.population > 1500000) + OR (place = 'city' + AND a.population > 40000000) + OR (place IS NULL + AND a.population > 40000000) +ORDER BY + place, + Population DESC; + +-- now store the inconstencies +WITH cities_x AS ( + SELECT + a.name, + a.name_en, + place, + osm_id, + replace(a.population, '.', '')::bigint population, + a.way + FROM + cities a + WHERE + a.population IS NOT NULL + AND isnumeric (a.population) + AND a.place IN ('village', 'town', 'city', 'municipality')) +SELECT + name, + name_en, + place, + population, + osm_id INTO TABLE cities_incon +FROM + cities_x a +WHERE (place = 'village' + AND a.population > 90000) + OR (place = 'town' + AND a.population > 1500000) + OR (place = 'city' + AND a.population > 40000000) +ORDER BY + place, + Population DESC; + +WITH cities_relx AS ( + SELECT + a.name, + a.name_en, + place, + osm_id, + replace(a.population, '.', '')::bigint population, + a.way + FROM + cities_rel a + WHERE + a.population IS NOT NULL + AND isnumeric (a.population) + AND a.place IN ('village', 'town', 'city', 'municipality')) +SELECT + name, + name_en, + place, + population, + osm_id INTO TABLE cities_rel_incon +FROM + cities_relx a +WHERE (place = 'village' + AND a.population > 90000) + OR (place = 'town' + AND a.population > 1500000) + OR (place = 'city' + AND a.population > 40000000) + OR (place IS NULL + AND a.population > 40000000) +ORDER BY + place, + Population DESC; + +-- and eliminate the inconsistencies +UPDATE + cities +SET + population = 0 +WHERE + osm_id IN ( + SELECT + osm_id + FROM + cities_incon); + +UPDATE + cities_rel +SET + population = 0 +WHERE + osm_id IN ( + SELECT + osm_id + FROM + cities_rel_incon); + SELECT now(); @@ -173,18 +1051,25 @@ SELECT -- clean the cities table (when population is null or population is not numeric or unusable) SELECT a.name, + a.name_en, replace(a.population, '.', '')::bigint population, - a.way INTO cities_ok + a.way INTO TABLE cities_ok FROM cities a WHERE a.population IS NOT NULL AND isnumeric (a.population) - AND a.place IN ('town', 'city', 'municipality'); + AND a.place IN ('village', 'town', 'city', 'municipality'); + +ANALYZE cities_ok; + +SELECT + now(); -- clean the cities_rel table (when population is not numeric or unusable) SELECT a.name AS name, + a.name_en AS name_en, a.place AS place, a.admin_level, CASE WHEN a.population IS NOT NULL @@ -193,20 +1078,26 @@ SELECT ELSE NULL END AS population, - a.way INTO cities_rel_ok + a.way INTO TABLE cities_rel_ok FROM cities_rel a WHERE - boundary = 'administrative'; + boundary IN ('administrative', 'ceremonial'); CREATE INDEX cities_ok_idx ON public.cities_ok USING gist (way) WITH (fillfactor = '100'); CREATE INDEX cities_rel_ok_idx ON public.cities_rel_ok USING gist (way) WITH (fillfactor = '100'); --- select town + population + way starting with cities_ok ... (to catch special cases as ex. "Berlin" which is tagged with "admin_level=4") +SELECT + now(); + +ANALYZE cities_rel_ok; + +-- select town + population + way starting with cities_ok .... (to catch specials cases as ex. "Berlin" which is tagged with "admin_level=4") -- SELECT a.name AS name, + a.name_en AS name_en, st_x (a.way), st_y (a.way), a.population, @@ -295,7 +1186,7 @@ LIMIT 1) AND a.name = b.name AND st_intersects (a.way, b.way)) LIMIT 1) --- Berlin admin_level=4! +-- Berlin admin_level=4! , but Beijing/Shangai administrative-regions have the same name and area>20000 km*2 !!! WHEN ( SELECT way @@ -324,7 +1215,7 @@ LIMIT 1) cities_rel_ok b WHERE (st_area (b.way) / 1000000 < 10000 AND b.admin_level IS NULL - AND b.place IN ('city', 'town') + AND b.place IN ('town', 'city', 'village', 'municipality') AND a.name = b.name AND st_intersects (a.way, b.way)) LIMIT 1) IS NOT NULL THEN @@ -335,7 +1226,7 @@ LIMIT 1) cities_rel_ok b WHERE (st_area (b.way) / 1000000 < 10000 AND b.admin_level IS NULL - AND b.place IN ('city', 'town') + AND b.place IN ('town', 'city', 'village', 'municipality') AND a.name = b.name AND st_intersects (a.way, b.way)) LIMIT 1) @@ -347,7 +1238,7 @@ LIMIT 1) cities_rel_ok b WHERE (st_area (b.way) / 1000000 < 10000 AND b.admin_level = '2' - AND b.place IN ('city', 'town') + AND b.place IN ('town', 'city', 'village', 'municipality') AND a.name = b.name AND st_intersects (a.way, b.way)) LIMIT 1) IS NOT NULL THEN @@ -358,7 +1249,7 @@ LIMIT 1) cities_rel_ok b WHERE (st_area (b.way) / 1000000 < 10000 AND b.admin_level = '2' - AND b.place IN ('city', 'town') + AND b.place IN ('town', 'city', 'village', 'municipality') AND a.name = b.name AND st_intersects (a.way, b.way)) LIMIT 1) @@ -376,9 +1267,17 @@ FROM ORDER BY name; --- select town + population + way starting with cities_rel_ok ... +CREATE INDEX cities_intermed3_idx ON public. cities_intermed3 USING gist (way) WITH (fillfactor = '100'); + +SELECT + now(); + +ANALYZE cities_intermed3; + +-- select town + population + way starting with cities_rel_ok .... SELECT a.name AS name, + a.name_en AS name_en, st_area (a.way) st_area, CASE WHEN a.population IS NOT NULL THEN a.population @@ -398,43 +1297,52 @@ FROM cities_rel_ok a WHERE a.admin_level = '8' + AND (a.place IS NULL + OR a.place IN ('town', 'city', 'village', 'municipality')) ORDER BY a.name; --- merge SELECT - name, - max(population) AS population, - way, - max(way0) AS way0, - st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography) AS merca_coef INTO cities_intermed5 -FROM (( - SELECT - name, - population, - way, - way0 - FROM - cities_intermed3) - UNION ( - SELECT - name, - population, - way, - way0 - FROM - cities_intermed4)) a -WHERE - population IS NOT NULL - -- and population > 20000 -GROUP BY - name, - way -ORDER BY - population; + now(); +-- merge +WITH intermed5 AS ( + SELECT + name, + max(name_en) AS name_en, + max(population) AS population, + way, + max(way0) AS way0, + st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography) AS merca_coef + FROM (( + SELECT + name, + name_en, + population, + way, + way0 + FROM + cities_intermed3) + UNION ( + SELECT + name, + name_en, + population, + way, + way0 + FROM + cities_intermed4)) a + WHERE + population IS NOT NULL + GROUP BY + name, + way + ORDER BY + population +) SELECT name, + name_en, population, way, CASE WHEN way0 IS NULL THEN @@ -443,565 +1351,16 @@ SELECT way0::geometry END AS way0, merca_coef INTO TABLE cities_all -FROM - cities_intermed5; - -SELECT - now(); - --- create tags for noise --- create raw data for noise coming from cars --- when several highways-segments are producing noise, aggregate the noises using the "ST_Union" of the segments! --- (better as using "sum" or "max" that do not deliver good factors) -SELECT - * INTO TABLE osm_line_noise -FROM - osm_line_buf_50 q -WHERE - q.highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link', 'primary', 'primary_link', 'secondary'); - -CREATE INDEX osm_line_noise_ind ON public.osm_line_noise USING gist (way) WITH (fillfactor = '100'); - -SELECT - now(); - -SELECT - m.osm_id losmid, - m.highway lhighway, - q.highway AS qhighway, - q.maxspeed_class, - st_area (st_intersection (m.way, ST_Union (q.way))) / st_area (m.way) AS noise_factor INTO TABLE noise_part0 -FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_noise AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link') - AND q.maxspeed_class < 1.1 -GROUP BY - losmid, - lhighway, - m.way, - q.highway, - q.maxspeed_class -ORDER BY - noise_factor DESC; - -SELECT - now(); - -SELECT - m.osm_id losmid, - m.highway lhighway, - q.highway AS qhighway, - q.maxspeed_class, - st_area (st_intersection (m.way, ST_Union (q.way))) / (1.5 * st_area (m.way)) AS noise_factor INTO TABLE noise_part1 -FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_noise AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.highway IN ('motorway', 'motorway_link', 'trunk', 'trunk_link') - AND q.maxspeed_class >= 1.1 -GROUP BY - losmid, - lhighway, - m.way, - q.highway, - q.maxspeed_class -ORDER BY - noise_factor DESC; - -SELECT - now(); - -SELECT - m.osm_id losmid, - m.highway lhighway, - q.highway AS qhighway, - q.maxspeed_class, - st_area (st_intersection (m.way, ST_Union (q.way))) / (2 * st_area (m.way)) AS noise_factor INTO TABLE noise_part2 -FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_noise AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.highway IN ('primary', 'primary_link') - AND q.maxspeed_class < 2.1 -GROUP BY - losmid, - lhighway, - m.way, - q.highway, - q.maxspeed_class -ORDER BY - noise_factor DESC; - -SELECT - now(); - -SELECT - m.osm_id losmid, - m.highway lhighway, - q.highway AS qhighway, - q.maxspeed_class, - st_area (st_intersection (m.way, ST_Union (q.way))) / (3 * st_area (m.way)) AS noise_factor INTO TABLE noise_part3 -FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_noise AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.highway IN ('primary', 'primary_link') - AND q.maxspeed_class >= 2.1 -GROUP BY - losmid, - lhighway, - m.way, - q.highway, - q.maxspeed_class -ORDER BY - noise_factor DESC; - -SELECT - now(); - -SELECT - m.osm_id losmid, - m.highway lhighway, - q.highway AS qhighway, - q.maxspeed_class, - st_area (st_intersection (m.way, ST_Union (q.way))) / (3 * st_area (m.way)) AS noise_factor INTO TABLE noise_part4 -FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_noise AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.highway IN ('secondary') - AND q.maxspeed_class < 2.1 -GROUP BY - losmid, - lhighway, - m.way, - q.highway, - q.maxspeed_class -ORDER BY - noise_factor DESC; - -SELECT - now(); - -SELECT - m.osm_id losmid, - m.highway lhighway, - q.highway AS qhighway, - q.maxspeed_class, - st_area (st_intersection (m.way, ST_Union (q.way))) / (5 * st_area (m.way)) AS noise_factor INTO TABLE noise_part5 -FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_noise AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.highway IN ('secondary') - AND q.maxspeed_class >= 2.1 -GROUP BY - losmid, - lhighway, - m.way, - q.highway, - q.maxspeed_class -ORDER BY - noise_factor DESC; - -SELECT - now(); - --- MERGE -SELECT - losmid, - sum(noise_factor) AS sum_noise_factor INTO TABLE noise_tmp2 FROM ( SELECT - losmid, - noise_factor + * FROM - noise_part0 - UNION - SELECT - losmid, - noise_factor - FROM - noise_part1 - UNION - SELECT - losmid, - noise_factor - FROM - noise_part2 - UNION - SELECT - losmid, - noise_factor - FROM - noise_part3 - UNION - SELECT - losmid, - noise_factor - FROM - noise_part4 - UNION - SELECT - losmid, - noise_factor - FROM - noise_part5) AS abcd -GROUP BY - losmid -ORDER BY - sum_noise_factor DESC; + intermed5 a) b; SELECT now(); --- noise coming from airports -SELECT - name, - st_buffer (way, (643 * st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 3857)) / st_length (ST_Transform (st_makeline (st_startpoint (way), st_centroid (way)), 4326)::geography))) AS way INTO TABLE poly_airport -FROM - polygons -WHERE - aeroway = 'aerodrome' - AND aerodrome = 'international'; - -SELECT - m.osm_id losmid, - st_area (st_intersection (m.way, q.way)) / (st_area (m.way) * 1.5) AS dist_factor INTO TABLE noise_airport -FROM - osm_line_buf_50 AS m - INNER JOIN poly_airport AS q ON ST_intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - --GROUP BY losmid, m.way -ORDER BY - dist_factor DESC; - --- add car & airport noises -SELECT - losmid, - sum(noise_factor) AS sum_noise_factor INTO TABLE noise_tmp3 -FROM (( - SELECT - losmid, - sum_noise_factor AS noise_factor - FROM - noise_tmp2 AS nois1) - UNION ( - SELECT - losmid, - dist_factor AS noise_factor - FROM - noise_airport AS nois2)) AS nois_sum -GROUP BY - losmid; - --- create the noise classes -SELECT - losmid, - CASE WHEN y.sum_noise_factor < 0.1 THEN - '1' - WHEN y.sum_noise_factor < 0.25 THEN - '2' - WHEN y.sum_noise_factor < 0.4 THEN - '3' - WHEN y.sum_noise_factor < 0.55 THEN - '4' - WHEN y.sum_noise_factor < 0.8 THEN - '5' - ELSE - '6' - END AS noise_class INTO TABLE noise_tags -FROM - noise_tmp3 y -WHERE - y.sum_noise_factor > 0.01; - -SELECT - count(*) -FROM - noise_tags; - -SELECT - noise_class, - count(*) -FROM - noise_tags -GROUP BY - noise_class -ORDER BY - noise_class; - -DROP TABLE noise_tmp2; - -SELECT - now(); - --- create tags for river -SELECT - xid, - sum(water_river_see) AS river_see INTO TABLE river_tmp -FROM ( - SELECT - m.osm_id AS xid, - st_area (st_intersection (m.way, ST_Union (q.way))) / st_area (m.way) AS water_river_see - FROM - osm_line_buf_50 AS m - INNER JOIN osm_poly_buf_120 AS q ON ST_Intersects (m.way, q.way) - WHERE - m.highway IS NOT NULL - -- and st_area(q.way) > 90746 !!! filter on very small surfaces was set above !!!!!!!!! - AND q.natural IN ('water', 'bay', 'beach', 'wetland') - AND (q.water IS NULL - OR q.water NOT IN ('wastewater')) - AND (st_area (ST_Transform (q.way, 4326)::geography) / 1000000) < 5000 - GROUP BY - m.osm_id, - m.way - UNION - SELECT - m.osm_id AS xid, - st_area (st_intersection (m.way, ST_Union (q.way))) / st_area (m.way) AS water_river_see - FROM - osm_line_buf_50 AS m - INNER JOIN osm_poly_coastline_buf_100 AS q ON ST_Intersects (m.way, q.way) - WHERE - m.highway IS NOT NULL - -- and st_area(q.way) > 90746 !!! filter on very small surfaces was set above !!!!!!!!! - GROUP BY - m.osm_id, - m.way - UNION - SELECT - m.osm_id AS xid, - st_area (st_intersection (m.way, ST_Union (q.way))) / st_area (m.way) AS water_river_see - FROM - osm_line_buf_50 AS m - INNER JOIN osm_line_water AS q ON ST_Intersects (m.way, q.way) - WHERE - m.highway IS NOT NULL - AND (st_area (ST_Transform (q.way, 4326)::geography) / 1000000) < 5000 - GROUP BY - m.osm_id, - m.way) AS abcd -GROUP BY - xid -ORDER BY - river_see DESC; - -SELECT - y.xid losmid, - CASE WHEN y.river_see < 0.17 THEN - '1' - WHEN y.river_see < 0.35 THEN - '2' - WHEN y.river_see < 0.57 THEN - '3' - WHEN y.river_see < 0.80 THEN - '4' - WHEN y.river_see < 0.95 THEN - '5' - ELSE - '6' - END AS river_class INTO TABLE river_tags -FROM - river_tmp y -WHERE - y.river_see > 0.05; - -SELECT - count(*) -FROM - river_tags; - -SELECT - river_class, - count(*) -FROM - river_tags -GROUP BY - river_class -ORDER BY - river_class; - -SELECT - now(); - --- create tags for forest -SELECT - m.osm_id, - m.highway, - st_area (st_intersection (m.way, ST_Union (q.way))) / st_area (m.way) AS green_factor INTO TABLE forest_tmp -FROM - osm_line_buf_50 AS m - INNER JOIN osm_poly_no_buf AS q ON ST_Intersects (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND ((q.landuse IN ('forest', 'allotments', 'flowerbed', 'orchard', 'vineyard', 'recreation_ground', 'village_green')) - OR q.leisure IN ('garden', 'park', 'nature_reserve')) - AND (st_area (ST_Transform (q.way, 4326)::geography) / 1000000) < 5000 -GROUP BY - m.osm_id, - m.highway, - m.way -ORDER BY - green_factor DESC; - --- -SELECT - y.osm_id losmid, - CASE WHEN y.green_factor < 0.1 THEN - NULL - WHEN y.green_factor < 0.2 THEN - '1' - WHEN y.green_factor < 0.4 THEN - '2' - WHEN y.green_factor < 0.6 THEN - '3' - WHEN y.green_factor < 0.8 THEN - '4' - WHEN y.green_factor < 0.98 THEN - '5' - ELSE - '6' - END AS forest_class INTO TABLE forest_tags -FROM - forest_tmp y -WHERE - y.green_factor > 0.1; - -SELECT - count(*) -FROM - forest_tags; - -SELECT - forest_class, - count(*) -FROM - forest_tags -GROUP BY - forest_class -ORDER BY - forest_class; - -SELECT - now(); - --- create "town" tags --- get the highways within the town -SELECT - m.osm_id losmid, - m.highway lhighway, - CASE WHEN q.population::decimal > '2000000' THEN - 1 - WHEN q.population::decimal > '1000000' THEN - 0.8 - WHEN q.population::decimal > '400000' THEN - 0.6 - WHEN q.population::decimal > '150000' THEN - 0.4 - WHEN q.population::decimal > '80000' THEN - 0.2 - ELSE - 0.1 - END AS town_factor INTO TABLE town_tmp -FROM - osm_line_buf_50 AS m - --INNER JOIN cities_all AS q ON ST_Intersects(m.way, q.way) - INNER JOIN cities_all AS q ON ST_Within (m.way, q.way) -WHERE - m.highway IS NOT NULL - AND q.population > '50000' -ORDER BY - town_factor DESC; - --- -SELECT - losmid, - CASE WHEN y.town_factor = 0.1 THEN - '1' - WHEN y.town_factor = 0.2 THEN - '2' - WHEN y.town_factor = 0.4 THEN - '3' - WHEN y.town_factor = 0.6 THEN - '4' - WHEN y.town_factor = 0.8 THEN - '5' - ELSE - '6' - END AS town_class INTO TABLE town_tags -FROM ( - SELECT - losmid, - max(town_factor) AS town_factor - FROM - town_tmp y - GROUP BY - losmid) y; - -SELECT - count(*) -FROM - town_tags; - -SELECT - town_class, - count(*) -FROM - town_tags -GROUP BY - town_class -ORDER BY - town_class; - --- --- subtract the ways from town with a green tag (because administrative surface are sometimes too large) --- -DELETE FROM town_tags -WHERE losmid IN ( - SELECT - losmid - FROM - forest_tags - WHERE - forest_class NOT IN ('1')); - -DELETE FROM town_tags -WHERE losmid IN ( - SELECT - losmid - FROM - river_tags - WHERE - river_class NOT IN ('1')); - -SELECT - count(*) -FROM - town_tags; - -SELECT - town_class, - count(*) -FROM - town_tags -GROUP BY - town_class -ORDER BY - town_class; - -SELECT - now(); +ANALYZE cities_all; ------------------------------------------- -- create tags for TRAFFIC @@ -1035,7 +1394,6 @@ FROM INNER JOIN cities_all AS q ON ST_DWithin (m.way0, q.way0, ((3215 * q.merca_coef) + ((64300 * q.merca_coef) * q.population / (q.population + 10000)))) WHERE m.highway IS NOT NULL - --and m.highway in ('primary','primary_link','secondary', 'secondary_link', 'tertiary') AND q.population > 200 GROUP BY m.osm_id, @@ -1047,8 +1405,10 @@ ORDER BY SELECT now(); +ANALYZE traffic_tmp; + -- prepare some special tables --- the intersections motorway_link with primary/secondary/tertiary deliver the motorway accesses... +-- the intersections motorway_link with primary/secondary/tertiary deliver the motorway acccesses.... SELECT * INTO TABLE lines_link FROM @@ -1086,6 +1446,8 @@ CREATE INDEX motorway_access_idx3 ON public.motorway_access USING gist (way3) WI SELECT now(); +ANALYZE motorway_access; + -- find out all the primary/secondary/tertiary within 1000 m and 2000 m from a motorway access SELECT now(); @@ -1109,7 +1471,7 @@ SELECT SELECT m.osm_id losmid, - sum(st_length (q.way) / (6430 * merca_coef)) motorway_factor INTO TABLE motorway_access_2000 + sum(st_length (q.way) / (6430 * q.merca_coef)) motorway_factor INTO TABLE motorway_access_2000 FROM lines AS m INNER JOIN motorway_access AS q ON ST_Intersects (m.way, q.way3) @@ -1124,6 +1486,8 @@ ORDER BY SELECT now(); +ANALYZE motorway_access_2000; + -- -- special regions: mountain_range with "peaks" ==> few highways ==> higher traffic !!! -- calculate the "peak_density" @@ -1139,6 +1503,7 @@ FROM INNER JOIN peak AS q ON ST_Intersects (m.way2, q.way) WHERE (q.ele ~ '^[0-9\.]+$') AND q.ele::decimal > 400 + -- where (q.ele not ~ '^\d+(\.\d+)?$') and q.ele :: decimal > 400 GROUP BY m.osm_id, m.way @@ -1164,17 +1529,21 @@ FROM WHERE (landuse IN ('industrial', 'retail')) OR (aeroway = 'aerodrome' AND aerodrome = 'international') - --where landuse in ('industrial', 'retail') - --where landuse in ('industrial') AND (plant_method IS NULL OR plant_method NOT IN ('photovoltaic')) AND (plant_source IS NULL OR plant_source NOT IN ('solar', 'wind')); +SELECT + now(); + +ANALYZE poly_industri; + SELECT name, way, ST_Centroid (way) way0, + ST_Buffer (way, 12860 * merca_coef) AS way2, st_area (way) * power(50 / (32.15 * merca_coef), 2) areaReal, merca_coef INTO industri FROM @@ -1197,7 +1566,7 @@ SELECT END AS industrial_factor INTO industri_tmp FROM primsecter15k AS m - INNER JOIN industri AS q ON ST_dwithin (m.way0, q.way0, (12860 * q.merca_coef)) + INNER JOIN industri AS q ON ST_intersects (m.way0, q.way2) GROUP BY m.osm_id, m.highway, @@ -1363,7 +1732,7 @@ GROUP BY SELECT now(); --- Do not apply the positive effect of "motorway density" in proximity of motorway accesses!!!! +-- Do not apply the positiv effect of "motorway density" in proximity of motorway accesses!!!! UPDATE except_all SET @@ -1375,11 +1744,11 @@ WHERE FROM motorway_access_2000); --- quite direct at motorway accesses set a negative effect !!!! +-- quite direct at motorway accesses set a negativ effect !!!! UPDATE except_all SET - motorway_factor = - 15 + motorway_factor = -15 WHERE losmid IN ( SELECT @@ -1427,6 +1796,120 @@ GROUP BY ORDER BY traffic_class; +-- create town tags................. +-- create "town" tags +-- get the highways within the town +SELECT + m.osm_id losmid, + m.highway lhighway, + CASE WHEN q.population::decimal > '2000000' THEN + 1 + WHEN q.population::decimal > '1000000' THEN + 0.8 + WHEN q.population::decimal > '400000' THEN + 0.6 + WHEN q.population::decimal > '150000' THEN + 0.4 + WHEN q.population::decimal > '80000' THEN + 0.2 + ELSE + 0.1 + END AS town_factor INTO TABLE town_tmp +FROM + lines AS m + INNER JOIN cities_all AS q ON ST_Within (m.way, q.way) +WHERE + m.highway IS NOT NULL + AND q.population > '50000' +ORDER BY + town_factor DESC; + +SELECT + now(); + +ANALYSE town_tmp; + +-- +SELECT + losmid::bigint, + CASE WHEN y.town_factor = 0.1 THEN + '1' + WHEN y.town_factor = 0.2 THEN + '2' + WHEN y.town_factor = 0.4 THEN + '3' + WHEN y.town_factor = 0.6 THEN + '4' + WHEN y.town_factor = 0.8 THEN + '5' + ELSE + '6' + END AS town_class INTO TABLE town_tags +FROM ( + SELECT + losmid, + max(town_factor) AS town_factor + FROM + town_tmp y + GROUP BY + losmid) y; + +ANALYSE town_tags; + +SELECT + count(*) +FROM + town_tags; + +SELECT + town_class, + count(*) +FROM + town_tags +GROUP BY + town_class +ORDER BY + town_class; + +-- +-- substract the ways from town with a green tag (because administrative surface are some times too large) +-- +DELETE FROM town_tags +WHERE losmid IN ( + SELECT + losmid + FROM + forest_tags + WHERE + forest_class NOT IN ('1')); + +DELETE FROM town_tags +WHERE losmid IN ( + SELECT + losmid + FROM + river_tags + WHERE + river_class NOT IN ('1')); + +SELECT + count(*) +FROM + town_tags; + +SELECT + town_class, + count(*) +FROM + town_tags +GROUP BY + town_class +ORDER BY + town_class; + +SELECT + now(); + -- -- put all tags together in 1 table (1 "direct" access per way in mapcreator) -- @@ -1452,7 +1935,7 @@ ORDER BY CREATE INDEX all_tags_ind ON all_tags (losmid, noise_class, river_class, forest_class, town_class, traffic_class) WITH (fillfactor = '100'); -ANALYSE; +ANALYSE all_tags; SELECT now(); diff --git a/misc/scripts/mapcreation/brouter_cfg.lua b/misc/scripts/mapcreation/brouter_cfg.lua index 07604f6..6998a69 100644 --- a/misc/scripts/mapcreation/brouter_cfg.lua +++ b/misc/scripts/mapcreation/brouter_cfg.lua @@ -18,6 +18,7 @@ tables.lines = osm2pgsql.define_way_table('lines', { { column = 'waterway', type = 'text' }, { column = 'natural', type = 'text' }, { column = 'width', type = 'text' }, + { column = 'oneway', type = 'text' }, { column = 'way', type = 'linestring', projection = srid, not_null = true }, }) @@ -43,6 +44,7 @@ tables.polygons = osm2pgsql.define_area_table('polygons', { tables.cities = osm2pgsql.define_node_table('cities', { { column = 'name', type = 'text' }, + { column = 'name_en', type = 'text' }, { column = 'place', type = 'text' }, { column = 'admin_level', type = 'text' }, { column = 'osm_id', type = 'text' }, @@ -56,6 +58,7 @@ tables.cities_rel = osm2pgsql.define_relation_table('cities_rel', { { column = 'admin_level', type = 'text' }, { column = 'boundary', type = 'text' }, { column = 'name', type = 'text' }, + { column = 'name_en', type = 'text' }, { column = 'place', type = 'text' }, { column = 'osm_id', type = 'text' }, { column = 'population', type = 'text' }, @@ -114,10 +117,11 @@ end function osm2pgsql.process_node(object) - if (object.tags.place == 'city' or object.tags.place == 'town' or object.tags.place == 'municipality') and has_area_tags(object.tags) then +if (object.tags.place == 'city' or object.tags.place == 'town' or object.tags.place == 'village' or object.tags.place == 'municipality') and has_area_tags(object.tags) then tables.cities:insert({ osm_id = object.id, name = object.tags.name, + name_en = object.tags['name:en'], place = object.tags.place, admin_level = object.tags.admin_level, population = object.tags.population, @@ -166,6 +170,7 @@ function osm2pgsql.process_way(object) natural = object.tags.natural, width = object.tags.width, maxspeed = object.tags.maxspeed, + oneway = object.tags.oneway, way = object:as_linestring() }) end @@ -202,6 +207,7 @@ function osm2pgsql.process_relation(object) boundary = object.tags.boundary, admin_level = object.tags.admin_level, name = object.tags.name, + name_en = object.tags['name:en'], place = object.tags.place, population = object.tags.population, osm_id = object.id,