feat(db): add bike ride stations to update-db.sh

This commit is contained in:
dancingCycle 2023-07-31 14:30:34 +02:00
parent c72ec3aab5
commit 278dfcd03b
3 changed files with 63 additions and 0 deletions

22
db/bike-ride.sh Normal file
View File

@ -0,0 +1,22 @@
#!/bin/bash
#
echo "Started..."
#Started...
#
# special variable $# is the number of arguments
if [ $# -lt 3 ] ; then
echo 'Call ./<script> <db name> <db user> <db schema>'
exit 1
fi
#
DB_NAME="$1"
echo "DB_NAME: $DB_NAME"
DB_USER="$2"
echo "DB_USER: $DB_USER"
DB_SCHEMA="$3"
echo "DB_SCHEMA: ${DB_SCHEMA}"
#
psql -U $DB_USER -f ./sql/scripts/bike-ride.sql -d $DB_NAME -v schema=$DB_SCHEMA
#
echo "Done."
#done.

View File

@ -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_bike_ride;
DROP VIEW IF EXISTS :schema.vw_bike_ride;
CREATE OR REPLACE VIEW :schema.vw_bike_ride AS
SELECT entity.osm_id, entity.bike_ride, entity.name, entity.st_x, entity.st_y
FROM (
--planet_osm_point/node
SELECT osmNode.osm_id, osmNode.bike_ride, 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.bike_ride != 'no'
AND osmNode.bike_ride IS NOT NULL
AND osmNode.proposed IS NULL
UNION
--planet_osm_polygone/way
SELECT osmWay.osm_id, osmWay.bike_ride, 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.bike_ride != 'no'
AND osmWay.bike_ride 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_bike_ride AS SELECT * FROM :schema.vw_bike_ride;

View File

@ -22,6 +22,8 @@ psql -U $DB_USER -f ./sql/scripts/vw_municipalities.sql -d $DB_NAME -v schema=$D
#
psql -U $DB_USER -f ./sql/scripts/bus-stop.sql -d $DB_NAME -v schema=$DB_SCHEMA
#
psql -U $DB_USER -f ./sql/scripts/bike-ride.sql -d $DB_NAME -v schema=$DB_SCHEMA
#
psql -U $DB_USER -f ./sql/scripts/park-ride.sql -d $DB_NAME -v schema=$DB_SCHEMA
#
psql -U $DB_USER -f ./sql/scripts/poi.sql -d $DB_NAME -v schema=$DB_SCHEMA