From 82a9c1b0e051556c83b8dc7d6a2f5c60ca81ae38 Mon Sep 17 00:00:00 2001 From: "Begerad, Stefan" Date: Mon, 31 Jul 2023 16:50:28 +0200 Subject: [PATCH] feat(db): add ticket offices and machines to update-db.sh --- db/sql/scripts/ticket-machine.sql | 39 +++++++++++++++++++ .../{sales-point.sql => ticket-office.sql} | 18 +++------ db/update-db.sh | 4 +- 3 files changed, 48 insertions(+), 13 deletions(-) create mode 100644 db/sql/scripts/ticket-machine.sql rename db/sql/scripts/{sales-point.sql => ticket-office.sql} (76%) diff --git a/db/sql/scripts/ticket-machine.sql b/db/sql/scripts/ticket-machine.sql new file mode 100644 index 0000000..0c65806 --- /dev/null +++ b/db/sql/scripts/ticket-machine.sql @@ -0,0 +1,39 @@ +-- 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_sale_points; +DROP VIEW IF EXISTS :schema.vw_sale_points; + +CREATE OR REPLACE VIEW :schema.vw_sale_points AS +SELECT entity.osm_id, entity.sale_points, entity.name, entity.st_x, entity.st_y +FROM ( +--planet_osm_point/node +SELECT osmNode.osm_id, osmNode.amenity, 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.amenity = 'vending_machine' + AND osmNode.vending = 'public_transport_tickets' + AND osmNode.proposed IS NULL +UNION +--planet_osm_polygone/way +SELECT osmWay.osm_id, osmWay.amenity, 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.amenity = 'vending_machine' + AND osmWay.vending = 'public_transport_tickets' + 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_sale_points AS SELECT * FROM :schema.vw_sale_points; diff --git a/db/sql/scripts/sales-point.sql b/db/sql/scripts/ticket-office.sql similarity index 76% rename from db/sql/scripts/sales-point.sql rename to db/sql/scripts/ticket-office.sql index 2a3c982..4dbc0f4 100644 --- a/db/sql/scripts/sales-point.sql +++ b/db/sql/scripts/ticket-office.sql @@ -9,31 +9,25 @@ CREATE OR REPLACE VIEW :schema.vw_sale_points AS SELECT entity.osm_id, entity.sale_points, entity.name, entity.st_x, entity.st_y FROM ( --planet_osm_point/node -SELECT osmNode.osm_id, osmNode.sale_points, osmNode.name, +SELECT osmNode.osm_id, osmNode."tickets:public_transport", 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' + osmNode.shop = 'ticket' AND osmNode."tickets:public_transport" != 'no' - AND osmNode."tickets:public_transport" IS NOT NULL) - OR - (osmNode.amenity = 'vending_machine' - AND osmNode.vending = 'public_transport_tickets') + AND osmNode."tickets:public_transport" IS NOT NULL AND osmNode.proposed IS NULL UNION --planet_osm_polygone/way -SELECT osmWay.osm_id, osmWay.sale_points, osmWay.name, +SELECT osmWay.osm_id, osmWay."tickets:public_transport", 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' + osmWay.shop = 'ticket' AND osmWay."tickets:public_transport" != 'no' - AND osmWay."tickets:public_transport" IS NOT NULL) - OR - (osmWay.amenity = 'vending_machine' - AND osmWay.vending = 'public_transport_tickets') + AND osmWay."tickets:public_transport" IS NOT NULL AND osmWay.proposed IS NULL ) AS entity --consider coordinates inside rvb only diff --git a/db/update-db.sh b/db/update-db.sh index 548b953..f0e6034 100644 --- a/db/update-db.sh +++ b/db/update-db.sh @@ -30,7 +30,9 @@ psql -U $DB_USER -f ./sql/scripts/poi.sql -d $DB_NAME -v schema=$DB_SCHEMA # psql -U $DB_USER -f ./sql/scripts/railway.sql -d $DB_NAME -v schema=$DB_SCHEMA # -psql -U $DB_USER -f ./sql/scripts/sales-point.sql -d $DB_NAME -v schema=$DB_SCHEMA +psql -U $DB_USER -f ./sql/scripts/ticket-office.sql -d $DB_NAME -v schema=$DB_SCHEMA +# +psql -U $DB_USER -f ./sql/scripts/ticket-machine.sql -d $DB_NAME -v schema=$DB_SCHEMA # echo "Done." #done.