osm-rvb/db/sql/scripts/bus-stop.sql

106 lines
3.9 KiB
SQL

-- colon before variable: for a prepared statement using named placeholders, this will be a parameter name of the form :name
CREATE SCHEMA IF NOT EXISTS :schema;
SET search_path to :schema, public;
DROP TABLE IF EXISTS :schema.tbl_bus_stop;
DROP VIEW IF EXISTS :schema.vw_bus_stop;
CREATE OR REPLACE VIEW :schema.vw_bus_stop AS
SELECT foo.id,
foo.osm_id,
foo.highway,
foo.name,
foo.operator,
foo.st_x,
foo.st_y,
foo.osm_typ,
foo.link AS osm_link,
foo.kategorie,
lk.name as landkreis,
CASE WHEN gem.name IS NULL THEN lk.name ELSE gem.name END as gemeinde,
st_geomfromtext('POINT(' || foo.st_x || ' ' || foo.st_y ||')',4326) as the_geom
FROM (
-- Block fuer den Bereich NODE
SELECT 'ON'||cast(p.osm_id as text) as id,
p.osm_id,
p.highway,
p.name AS name,
p.operator,
st_x(st_transform(p.way, 4326)) AS st_x,
st_y(st_transform(p.way, 4326)) AS st_y,
'node'::text AS osm_typ,
'http://www.openstreetmap.org/browse/node/'::text || p.osm_id AS link,
CASE WHEN p.highway = 'bus_stop' THEN 998 ELSE 999 END AS kategorie
FROM planet_osm_point p
WHERE p.proposed is null --- damit keine geplanten Gebäude etc übernommen werden
UNION
--- der Block für die Zuordnung WAY/POLYGON(ohne Relation d.h. OSM_id > 0)
SELECT 'OW'||cast(p.osm_id as text) as id,
p.osm_id,
p.highway,
p.name,
p.operator,
st_x(st_centroid(st_transform(p.way, 4326))) AS st_x,
st_y(st_centroid(st_transform(p.way, 4326))) AS st_y,
CASE
WHEN (p.osm_id < 0) THEN 'relation' else 'way' END as osm_typ,
CASE
--- bei Abspaltung Relation noch anpassen, mittlerweile überflüssig
WHEN p.osm_id < 0 THEN 'http://www.openstreetmap.org/browse/relation/' || p.osm_id *-1
WHEN p.osm_id > 0 THEN 'http://www.openstreetmap.org/browse/way/' || p.osm_id
END AS link,
CASE
WHEN p.highway = 'bus_stop' THEN 998
ELSE 999
END AS kategorie
---, st_transform(st_centroid(p.way), 4326) AS the_geom
FROM planet_osm_polygon p
WHERE p.proposed is null AND p.osm_id > 0 -- Ausschluss der Relationen
UNION
--- der Block für die Zuordnung Relation aus POLYGON/WAY (OSM_id < 0)
SELECT rel.id,
rel.osm_id,
rel.highway,
rel.name,
rel.operator,
avg(st_x) as st_x,
avg(st_y) as st_y,
rel.osm_typ,
rel.link,
rel.kategorie
FROM
(SELECT 'OR'||cast(p.osm_id * -1 as text) as id,
p.osm_id,
p.highway,
p.name,
p.operator,
st_x(st_centroid(st_transform(p.way, 4326))) AS st_x,
st_y(st_centroid(st_transform(p.way, 4326))) AS st_y,
CASE
WHEN (p.osm_id < 0) THEN 'relation' else 'way' END as osm_typ,
CASE
--- bei Abspaltung Relation noch anpassen
WHEN p.osm_id < 0 THEN 'http://www.openstreetmap.org/browse/relation/' || p.osm_id *-1
WHEN p.osm_id > 0 THEN 'http://www.openstreetmap.org/browse/way/' || p.osm_id
END AS link,
CASE
WHEN p.highway = 'bus_stop' THEN 998
ELSE 999
END AS kategorie
FROM planet_osm_polygon p
WHERE p.proposed is null AND p.osm_id < 0 -- Relationen
) as rel
GROUP BY
rel.id, rel.osm_id, rel.highway, rel.name, rel.operator, rel.osm_typ, rel.link, rel.kategorie
) AS foo
LEFT JOIN vw_counties lk ON st_contains(lk.way, st_transform(st_geomfromtext('POINT(' || foo.st_x || ' ' || foo.st_y ||')',4326),3857))
--- die Zuordnung erfolgt zu den Mitgliedsgemeinden (Admin 8)
LEFT JOIN vw_municipalities gem ON st_contains(gem.way, st_transform(st_geomfromtext('POINT(' || foo.st_x || ' ' || foo.st_y ||')',4326),3857))
WHERE (lk.name = ANY (ARRAY['Braunschweig','Salzgitter','Wolfsburg','Gifhorn','Landkreis Goslar','Landkreis Helmstedt','Landkreis Peine','Landkreis Wolfenbüttel'])) AND foo.name IS NOT NULL AND foo.kategorie <> 999
ORDER BY lk.name, gem.name, foo.kategorie, foo.name;
CREATE TABLE IF NOT EXISTS :schema.tbl_bus_stop AS SELECT * FROM :schema.vw_bus_stop;