osm-rvb/db/sql/scripts/ticket-office.sql

42 lines
1.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_shop_ticket;
DROP VIEW IF EXISTS :schema.vw_shop_ticket;
CREATE OR REPLACE VIEW :schema.vw_shop_ticket AS
SELECT entity.osm_id, entity.shop, entity.name, entity.st_x, entity.st_y
FROM (
--planet_osm_point/node
SELECT osmNode.osm_id, osmNode.shop, osmNode.name,
st_x(st_transform(osmNode.way, 4326)) AS st_x,
st_y(st_transform(osmNode.way, 4326)) AS st_y
FROM planet_osm_point AS osmNode
WHERE
osmNode.shop = 'ticket'
AND osmNode."tickets:public_transport" != 'no'
AND osmNode."tickets:public_transport" IS NOT NULL
AND osmNode.proposed IS NULL
UNION
--planet_osm_polygone/way
SELECT osmWay.osm_id, osmWay.shop, osmWay.name,
st_x(st_centroid(st_transform(osmWay.way, 4326))) AS st_x,
st_y(st_centroid(st_transform(osmWay.way, 4326))) AS st_y
FROM planet_osm_polygon AS osmWay
WHERE
osmWay.shop = 'ticket'
AND osmWay."tickets:public_transport" != 'no'
AND osmWay."tickets:public_transport" IS NOT NULL
AND osmWay.proposed IS NULL
) AS entity
--consider coordinates inside rvb only
LEFT JOIN vw_counties vwc ON st_contains(vwc.way, st_transform(st_geomfromtext('POINT(' || entity.st_x || ' ' || entity.st_y ||')',4326),3857))
--consider coordinates inside rvb only
LEFT JOIN vw_municipalities vwm ON st_contains(vwm.way, st_transform(st_geomfromtext('POINT(' || entity.st_x || ' ' || entity.st_y ||')',4326),3857))
--consider counties of rvb only
WHERE (vwc.name = ANY (ARRAY['Braunschweig','Salzgitter','Wolfsburg','Gifhorn','Landkreis Goslar','Landkreis Helmstedt','Landkreis Peine','Landkreis Wolfenbüttel']))
ORDER BY vwc.name, vwm.name, entity.name;
CREATE TABLE IF NOT EXISTS :schema.tbl_shop_ticket AS SELECT * FROM :schema.vw_shop_ticket;