osm-rvb/db/sql/scripts/poi.sql

275 lines
16 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_poi;
DROP VIEW IF EXISTS :schema.vw_poi;
CREATE OR REPLACE VIEW :schema.vw_poi AS
SELECT foo.id, foo.osm_id, foo.name, foo.kategorie, lk.name as landkreis,
CASE WHEN gem.name IS NULL THEN lk.name ELSE gem.name END as gemeinde,
array_to_string(ARRAY[foo.amenity, foo.building, foo.historic, foo.information, foo.leisure, foo.office, foo.tourism, foo.sport, foo.landuse,
foo.shop, foo.recycling_type, foo.social_facility],',') as kat_sub,
foo.link AS osm_link,
foo.operator, array_to_string(ARRAY[foo.phone, foo.phone2], ' ') AS phone,
array_to_string(ARRAY[foo.website, foo.website2], ' ') AS website, foo.opening_hours, foo."addr:street" AS adr_street,
foo."addr:housenumber" AS adr_housenumber, foo."addr:postcode" AS adr_postcode, foo."addr:city" AS adr_city,
foo."addr:country" AS adr_country, foo.wikipedia, foo.st_x, foo.st_y, foo.osm_typ, 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.amenity, p.building, p.historic, p.information, p.leisure, p.office, p.tourism, p.sport, p.landuse, p.shop,
p.recycling_type, p.social_facility,
--- CASE Block um die Kurznamen bei Cambio abzufangen
CASE
WHEN p.amenity = 'car_sharing' THEN p.name || ' '||p.operator
ELSE p.name
END 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' AS osm_typ, 'http://www.openstreetmap.org/browse/node/' || p.osm_id AS link,
p."contact:website" AS website, p."contact:phone" AS phone, p.phone AS phone2, p.website AS website2, p.opening_hours,
p."addr:street", p."addr:housenumber", p."addr:postcode", p."addr:city", p."addr:country", p.wikipedia,
CASE
WHEN ((p.amenity IN ('nightclub','pub','bar','biergarten')) OR (p.amenity IN ('restaurant') AND "microbrewery" = 'yes')
AND (p.leisure NOT IN ('miniature_golf','pitch','sports_centre') OR p.leisure IS NULL))
THEN 16 --- Nachtleben
WHEN (p.amenity IN ('restaurant','cafe'))
AND ((p.historic NOT IN ('vessel')) OR p.historic IS NULL)
AND (("microbrewery" NOT IN ('yes')) OR "microbrewery" IS NULL)
AND ((p.tourism NOT IN ('museum')) OR p.tourism IS NULL)
THEN 15 --- Kulinarisches
WHEN p.amenity IN ('place_of_worship') OR (p.building IN ('church', 'cathedral'))
THEN 12 --- öff. Einrichtung
WHEN ((p.amenity IN ('cinema', 'theatre', 'arts_centre','exhibition_center'))
OR (p.tourism IN ('attraction','zoo','wine_cellar','museum'))
OR ("craft" = 'brewery')
OR (p.leisure IN ('escape_game'))
OR (p.historic IN ('momument','vessel')))
AND ((p.attraction NOT IN ('animal')) OR p.attraction IS NULL)
AND ("railway" NOT IN ('rail') OR "railway" IS NULL)
THEN 10 --- Freizeit Kultur
WHEN p.amenity IN ('public_building','university','library','townhall','school','college','courthouse','grave_yard','community_centre','music_school')
OR p.landuse = 'cemetery'
OR p.amenity = 'car_pooling'
OR (p.amenity = 'recycling' AND p.recycling_type = 'centre')
OR (p.amenity in ('social_facility' ) AND p.social_facility in('group_home', 'outreach', 'workshop'))
OR (p.tourism = 'information' AND p.information = 'office')
OR p.office IN ('government','administrative')
OR (p.building IN ('civic', 'public') AND (p.healthcare NOT IN ('centre') OR p.healthcare IS NULL) AND (p.tourism NOT IN ('attraction') OR p.tourism IS NULL))
THEN 12 --- öff. Einrichtung
WHEN p.amenity IN ('hospital', 'clinic', 'dentist', 'doctors', 'pharmacy') THEN 13 ---Gesundheit
WHEN p.healthcare IN ('doctor') OR p.healthcare IN ('centre') THEN 13 ---Gesundheit
WHEN p.leisure IN ('park','garden','water_park','miniature_golf','stadium','sports_centre','swimming_pool','bowling_alley')
OR p.landuse = 'forest'
OR p.tourism = 'theme_park'
OR ("natural" = 'water' AND water in ('pond','lake'))
OR ("natural" = 'moor')
OR p.amenity = 'swimming_pool'
OR p.sport in ('swimming','10pin','9pin','miniature_golf')
OR (p.highway = 'racing' AND p.sport = 'karting')
OR (p.tourism = 'attraction' AND "railway" = 'rail')
OR (p.building = 'sports_centre' AND p.sport = 'climbing')
THEN 19 --- Sport Erholung
WHEN p.tourism IN ('hotel', 'hostel', 'guest_house')
AND (p.amenity NOT IN ('restaurant', 'cafe', 'nightclub', 'pub','bar','biergarten') OR p.amenity IS null)
THEN 14 --- Unterkünfte
WHEN p.amenity = 'car_sharing' AND (lower(p.brand) not like '%cambio%' or p.brand is Null) THEN 9
WHEN p.shop IN ('mall', 'department_store') THEN 20 --- Einkaufen
--- Ergänzen zusätzlicher OSM Einträge, entfaellt zukünftig
WHEN p.osm_id = 2499505600 THEN 12 --- VBN öff. einrichtung
WHEN p.osm_id = 1510238876 THEN 10 --- Aussichtsplattform SAIL City
WHEN p.osm_id = 4676775532 THEN 19 --- Salzgrotte Revital
--- Zusaetzliche Punkte VBN
---WHEN id IN (SELECT osm_id FROM tbl_poi_zusatz WHERE aktiv = TRUE) THEN tbt_poi.zusatz.kat
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.amenity, p.building, p.historic, p.information, p.leisure, p.office, p.tourism, p.sport, p.landuse, p.shop,
p.recycling_type, p.social_facility, 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,
p."contact:website" AS website, p."contact:phone" AS phone,
p.phone AS phone2, p.website AS website2, p.opening_hours, p."addr:street", p."addr:housenumber", p."addr:postcode",
p."addr:city", p."addr:country", p.wikipedia,
CASE
WHEN ((p.amenity IN ('nightclub','pub','bar','biergarten')) OR (p.amenity IN ('restaurant') AND "microbrewery" = 'yes')
AND (p.leisure NOT IN ('miniature_golf','pitch','sports_centre') OR p.leisure IS NULL))
THEN 16 --- Nachtleben
WHEN (p.amenity IN ('restaurant','cafe'))
AND ((p.historic NOT IN ('vessel')) OR p.historic IS NULL)
AND (("microbrewery" NOT IN ('yes')) OR "microbrewery" IS NULL)
AND ((p.tourism NOT IN ('museum')) OR p.tourism IS NULL)
THEN 15 --- Kulinarisches
WHEN p.amenity IN ('place_of_worship') OR (p.building in('church', 'cathedral'))
THEN 12 --- öff. Einrichtung
WHEN ((p.amenity IN ('cinema', 'theatre', 'arts_centre','exhibition_center'))
OR (p.tourism IN ('attraction','zoo','wine_cellar','museum'))
OR ("craft" = 'brewery')
OR (p.historic IN ('momument','vessel')))
AND ((p.attraction NOT IN ('animal')) OR p.attraction IS NULL)
AND ("railway" NOT IN ('rail') OR "railway" IS NULL)
THEN 10 --- Freizeit Kultur
WHEN p.amenity IN ('public_building','university','library','townhall','school','college','courthouse','grave_yard','community_centre','music_school')
OR p.landuse = 'cemetery'
OR p.amenity = 'car_pooling'
OR (p.amenity = 'recycling' AND p.recycling_type = 'centre')
OR (p.amenity in ('social_facility' ) AND p.social_facility in('group_home', 'outreach', 'workshop'))
OR (p.tourism = 'information' AND p.information = 'office')
OR p.office IN ('government','administrative')
OR (p.building IN ('civic', 'public') AND (p.healthcare NOT IN ('centre') OR p.healthcare IS NULL) AND (p.tourism NOT IN ('attraction') OR p.tourism IS NULL))
THEN 12 --- öff. Einrichtung
WHEN p.amenity IN ('hospital', 'clinic', 'dentist', 'doctors', 'pharmacy') THEN 13 ---Gesundheit
WHEN p.healthcare IN ('doctor') OR p.healthcare IN ('centre') THEN 13 ---Gesundheit
WHEN p.leisure IN ('park','garden','water_park','miniature_golf','stadium','sports_centre','swimming_pool','bowling_alley')
OR p.landuse = 'forest'
OR p.tourism = 'theme_park'
OR ("natural" = 'water' AND water in ('pond','lake'))
OR ("natural" = 'moor')
OR p.amenity = 'swimming_pool'
OR p.sport in ('swimming','10pin','9pin','miniature_golf')
OR (p.highway = 'racing' AND p.sport = 'karting')
OR (p.tourism = 'attraction' AND "railway" = 'rail')
OR (p.building = 'sports_centre' AND p.sport = 'climbing')
THEN 19 --- Sport Erholung
WHEN p.tourism IN ('hotel', 'hostel', 'guest_house')
AND (p.amenity NOT IN ('restaurant', 'cafe', 'nightclub', 'pub','bar','biergarten') OR p.amenity IS null)
THEN 14 --- Unterkünfte
WHEN p.amenity = 'car_sharing' AND (lower(p.brand) not like '%cambio%' or p.brand is Null) THEN 9
WHEN p.shop IN ('mall' , 'department_store') THEN 20
--- Zusaetzliche Punkte VBN
---WHEN id IN (SELECT osm_id FROM tbl_poi_zusatz WHERE aktiv = TRUE) THEN tbt_poi.zusatz.kat
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
--- der Block für die Zuordnung Relation aus POLYGON/WAY (OSM_id < 0)
UNION
SELECT rel.id, rel.osm_id, rel.amenity, rel.building, rel.historic, rel.information, rel.leisure, rel.office, rel.tourism, rel.sport, rel.landuse, rel.shop,
rel.recycling_type, rel.social_facility, rel.name, rel.operator, avg(st_x) as st_x, avg(st_y) as st_y, rel.osm_typ, rel.link, rel.website, rel.phone, rel.phone2,
rel.website2, rel.opening_hours, rel."addr:street", rel."addr:housenumber", rel."addr:postcode", rel."addr:city", rel."addr:country", rel.wikipedia, rel.kategorie
FROM
(SELECT 'OR'||cast(p.osm_id * -1 as text) as id, p.osm_id, p.amenity, p.building, p.historic, p.information, p.leisure, p.office, p.tourism, p.sport, p.landuse, p.shop,
p.recycling_type, p.social_facility, 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,
p."contact:website" AS website, p."contact:phone" AS phone,
p.phone AS phone2, p.website AS website2, p.opening_hours, p."addr:street", p."addr:housenumber", p."addr:postcode",
p."addr:city", p."addr:country", p.wikipedia,
CASE
-- ausgehen
WHEN ((p.amenity IN ('nightclub','pub','bar','biergarten')) OR (p.amenity IN ('restaurant') AND "microbrewery" = 'yes')
AND (p.leisure NOT IN ('miniature_golf','pitch','sports_centre') OR p.leisure IS NULL))
THEN 16 --- Nachtleben
WHEN (p.amenity IN ('restaurant','cafe'))
AND ((p.historic NOT IN ('vessel')) OR p.historic IS NULL)
AND (("microbrewery" NOT IN ('yes')) OR "microbrewery" IS NULL)
AND ((p.tourism NOT IN ('museum')) OR p.tourism IS NULL)
THEN 15 --- Kulinarisches
WHEN p.amenity IN ('place_of_worship') OR (p.building in('church', 'cathedral'))
THEN 12 --- öff. Einrichtung
WHEN ((p.amenity IN ('cinema', 'theatre', 'arts_centre','exhibition_center'))
OR (p.tourism IN ('attraction','zoo','wine_cellar','museum'))
OR ("craft" = 'brewery')
OR (p.historic IN ('momument','vessel')))
AND ((p.attraction NOT IN ('animal')) OR p.attraction IS NULL)
AND ("railway" NOT IN ('rail') OR "railway" IS NULL)
THEN 10 --- Freizeit Kultur
WHEN p.amenity IN ('public_building','university','library','townhall','school','college','courthouse','grave_yard','community_centre','music_school')
OR p.landuse = 'cemetery'
OR p.amenity = 'car_pooling'
OR (p.amenity = 'recycling' AND p.recycling_type = 'centre')
OR (p.amenity in ('social_facility' ) AND p.social_facility in('group_home', 'outreach', 'workshop'))
OR (p.tourism = 'information' AND p.information = 'office')
OR p.office IN ('government','administrative')
OR (p.building IN ('civic', 'public') AND (p.healthcare NOT IN ('centre') OR p.healthcare IS NULL) AND (p.tourism NOT IN ('attraction') OR p.tourism IS NULL))
THEN 12 --- öff. Einrichtung
WHEN p.amenity IN ('hospital', 'clinic', 'dentist', 'doctors', 'pharmacy') THEN 13 ---Gesundheit
WHEN p.healthcare IN ('doctor') OR p.healthcare IN ('centre') THEN 13 ---Gesundheit
WHEN p.leisure IN ('park','garden','water_park','miniature_golf','stadium','sports_centre','swimming_pool','bowling_alley')
OR p.landuse = 'forest'
OR p.tourism = 'theme_park'
OR ("natural" = 'water' AND water in ('pond','lake'))
OR ("natural" = 'moor')
OR p.amenity = 'swimming_pool'
OR p.sport in ('swimming','10pin','9pin','miniature_golf')
OR (p.highway = 'racing' AND p.sport = 'karting')
OR (p.tourism = 'attraction' AND "railway" = 'rail')
OR (p.building = 'sports_centre' AND p.sport = 'climbing')
THEN 19 --- Sport Erholung
WHEN p.tourism IN ('hotel', 'hostel', 'guest_house')
AND (p.amenity NOT IN ('restaurant', 'cafe', 'nightclub', 'pub','bar','biergarten') OR p.amenity IS null)
THEN 14 --- Unterkünfte
WHEN p.amenity = 'car_sharing' AND (lower(p.brand) not like '%cambio%' or p.brand is Null) THEN 9
WHEN p.shop IN ('mall', 'department_store') THEN 20
--- Zusaetzliche Punkte VBN
---WHEN id IN (SELECT osm_id FROM tbl_poi_zusatz WHERE aktiv = TRUE) THEN tbt_poi.zusatz.kat
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.amenity, rel.building, rel.historic, rel.information, rel.leisure, rel.office, rel.tourism, rel.sport, rel.landuse, rel.shop,
rel.recycling_type, rel.social_facility, rel.name, rel.operator, rel.osm_typ, rel.link, rel.website, rel.phone, rel.phone2,
rel.website2, rel.opening_hours, rel."addr:street", rel."addr:housenumber", rel."addr:postcode", rel."addr:city", rel."addr:country",
rel.wikipedia, 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 :schema.tbl_poi AS SELECT * FROM :schema.vw_poi;