Refactor to use PostGIS database instead of gtfs tools
[busui.git] / include / db / route-dao.inc.php
blob:a/include/db/route-dao.inc.php -> blob:b/include/db/route-dao.inc.php
<?php <?php
   
  /*
  * Copyright 2010,2011 Alexander Sadleir
   
  Licensed under the Apache License, Version 2.0 (the "License");
  you may not use this file except in compliance with the License.
  You may obtain a copy of the License at
   
  http://www.apache.org/licenses/LICENSE-2.0
   
  Unless required by applicable law or agreed to in writing, software
  distributed under the License is distributed on an "AS IS" BASIS,
  WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
  See the License for the specific language governing permissions and
  limitations under the License.
  */
   
function getRoute($routeID) { function getRoute($routeID) {
/* global $conn;
def handle_json_GET_routerow(self, params): $query = "Select * from routes where route_id = :routeID LIMIT 1";
schedule = self.server.schedule debug($query, "database");
route = schedule.GetRoute(params.get('route', None)) $query = $conn->prepare($query);
return [transitfeed.Route._FIELD_NAMES, route.GetFieldValuesTuple()] $query->bindParam(":routeID", $routeID);
*/ $query->execute();
} if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetch(PDO :: FETCH_ASSOC);
  }
   
  function getRoutesByShortName($routeShortName) {
  global $conn;
  $query = "Select distinct route_id, route_short_name from routes where route_short_name = :routeShortName";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":routeShortName", $routeShortName);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
  }
   
  function getRouteHeadsigns($routeID) {
  global $conn;
  $query = "select stops.stop_name, trip_headsign, direction_id,max(service_id) as service_id, count(*)
  from routes join trips on trips.route_id = routes.route_id
  join stop_times on stop_times.trip_id = trips.trip_id join stops on
  stop_times.stop_id = stops.stop_id where trips.route_id = :routeID
  and stop_times.stop_sequence = 1 group by stops.stop_name, trip_headsign, direction_id having count(*) > 2";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":routeID", $routeID);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
  }
  function getRouteDescription($routeID, $directionID) {
  $trip = getRouteNextTrip($routeID, $directionID);
  $start = getTripStartingPoint($trip['trip_id']);
  $end = getTripDestination($trip['trip_id']);
  return "From ".$start['stop_name']." to ".$end['stop_name'];
  }
  function getRouteByFullName($routeFullName) {
  global $conn;
  $query = "Select * from routes where route_short_name||route_long_name = :routeFullName LIMIT 1";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":routeFullName", $routeFullName);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetch(PDO :: FETCH_ASSOC);
  }
   
function getRoutes() { function getRoutes() {
/* def handle_json_GET_routes(self, params): global $conn;
"""Return a list of all routes.""" $query = "Select * from routes order by route_short_name;";
schedule = self.server.schedule debug($query, "database");
result = [] $query = $conn->prepare($query);
for r in schedule.GetRouteList(): $query->execute();
servicep = None if (!$query) {
for t in schedule.GetTripList(): databaseError($conn->errorInfo());
if t.route_id == r.route_id: return Array();
servicep = t.service_period }
break return $query->fetchAll();
result.append( (r.route_id, r.route_short_name, r.route_long_name, servicep.service_id) ) }
result.sort(key = lambda x: x[1:3])  
return result function getRoutesByNumberSeries($routeNumberSeries = "") {
*/ global $conn;
} if (strlen($routeNumberSeries) == 1) {
  return getRoute($routeNumberSeries);
function findRouteByNumber($routeNumber) { }
/* $seriesMin = substr($routeNumberSeries, 0, -1) . "0";
def handle_json_GET_routesearch(self, params): $seriesMax = substr($routeNumberSeries, 0, -1) . "9";
"""Return a list of routes with matching short name.""" $query = "Select distinct routes.route_id,routes.route_short_name,routes.route_long_name,service_id from routes join trips on trips.route_id =
schedule = self.server.schedule routes.route_id join stop_times on stop_times.trip_id = trips.trip_id where to_number(route_short_name, 'FM999') between :seriesMin and :seriesMax OR route_short_name LIKE :routeNumberSeries order by route_short_name;";
routeshortname = params.get('routeshortname', None) debug($query, "database");
result = [] $query = $conn->prepare($query);
for r in schedule.GetRouteList(): $query->bindParam(":seriesMin", $seriesMin);
if r.route_short_name == routeshortname: $query->bindParam(":seriesMax", $seriesMax);
servicep = None $routeNumberSeries = "% " . substr($routeNumberSeries, 0, -1) . "%";
for t in schedule.GetTripList(): $query->bindParam(":routeNumberSeries", $routeNumberSeries);
if t.route_id == r.route_id: $query->execute();
servicep = t.service_period if (!$query) {
break databaseError($conn->errorInfo());
result.append( (r.route_id, r.route_short_name, r.route_long_name, servicep.service_id) ) return Array();
result.sort(key = lambda x: x[1:3]) }
return result return $query->fetchAll();
*/ }
}  
  function getRouteNextTrip($routeID, $directionID) {
function getRouteNextTrip($routeID) { global $conn;
/*  
def handle_json_GET_routetrips(self, params): $query = "select routes.route_id,direction_id,trips.trip_id,trip_headsign,departure_time from routes join trips on trips.route_id = routes.route_id
""" Get a trip for a route_id (preferablly the next one) """ join stop_times on stop_times.trip_id = trips.trip_id where arrival_time between :currentTime and :futureTime
schedule = self.server.schedule and routes.route_id = :routeID and trips.direction_id = :directionID order by
query = params.get('route_id', None).lower() arrival_time limit 1";
result = [] debug($query, "database");
for t in schedule.GetTripList(): $query = $conn->prepare($query);
if t.route_id == query: $query->bindParam(":currentTime", current_time());
try: $futureTime = current_time(strtotime(current_time() ." +2h"));
starttime = t.GetStartTime() if (date("h",strtotime(current_time()) > 22)) $futureTime = "23:59:59";
except: $query->bindParam(":futureTime", $futureTime);
print "Error for GetStartTime of trip #" + t.trip_id + sys.exc_info()[0] $query->bindParam(":routeID", $routeID);
else: $query->bindParam(":directionID", $directionID);
cursor = t._schedule._connection.cursor() $query->execute();
cursor.execute( databaseError($conn->errorInfo());
'SELECT arrival_secs,departure_secs FROM stop_times WHERE ' if (!$query) {
'trip_id=? ORDER BY stop_sequence DESC LIMIT 1', (t.trip_id,)) databaseError($conn->errorInfo());
(arrival_secs, departure_secs) = cursor.fetchone() return Array();
if arrival_secs != None: }
endtime = arrival_secs $r = $query->fetch(PDO :: FETCH_ASSOC);
elif departure_secs != None: return $r;
endtime = departure_secs }
else:  
endtime =0 function getRouteFirstTrip($routeID,$directionID) {
result.append ( (starttime, t.trip_id, endtime) ) global $conn;
return sorted(result, key=lambda trip: trip[2])  
*/ $query = "select * from routes join trips on trips.route_id = routes.route_id
} join stop_times on stop_times.trip_id = trips.trip_id where routes.route_id = :routeID
  and trips.direction_id = :directionID order by
?> arrival_time DESC limit 1";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":routeID", $routeID);
   
  $query->bindParam(":directionID", $directionID);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
   
  $r = $query->fetch(PDO :: FETCH_ASSOC);
  return $r;
  }
   
  function getRouteAtStop($routeID, $directionID, $stop_id) {
  $nextTrip = getRouteNextTrip($routeID, $directionID);
  if ($nextTrip['trip_id']) {
  foreach (getTripStopTimes($nextTrip['trip_id']) as $tripStop) {
  if ($tripStop['stop_id'] == $stop_id)
  return $tripStop;
  }
  }
  return Array();
  }
   
  function getRouteTrips($routeID, $directionID = "", $service_period = "") {
  global $conn;
  if ($service_period == "")
  $service_period = service_period();
  $service_ids = service_ids($service_period);
  $sidA = $service_ids[0];
  $sidB = $service_ids[1];
  $directionSQL = "";
  if ($directionID != "")
  $directionSQL = " and direction_id = :directionID ";
  $query = "select routes.route_id,trips.trip_id,service_id,arrival_time, stop_id, stop_sequence from routes join trips on trips.route_id = routes.route_id
  join stop_times on stop_times.trip_id = trips.trip_id where (service_id=:service_periodA OR service_id=:service_periodB)
  AND (routes.route_id = :routeID) " . $directionSQL . " and stop_sequence = '1' order by
  arrival_time ";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":routeID", $routeID);
  $query->bindParam(":service_periodA", $sidA);
  $query->bindParam(":service_periodB", $sidB);
  if ($directionSQL != "")
  $query->bindParam(":directionID", $directionID);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
  }
   
  function getRoutesByDestination($destination = "", $service_period = "") {
  global $conn;
  if ($service_period == "")
  $service_period = service_period();
  $service_ids = service_ids($service_period);
  $sidA = $service_ids[0];
  $sidB = $service_ids[1];
  if ($destination != "") {
  /* $query = "SELECT DISTINCT trips.route_id,route_short_name,route_long_name, service_id
  FROM stop_times join trips on trips.trip_id =
  stop_times.trip_id join routes on trips.route_id = routes.route_id
  WHERE route_long_name = :destination AND (service_id=:service_periodA OR service_id=:service_periodB)
  order by route_short_name";*/
  $query = "select route_id, direction_id, stop_name, b.trip_id, b.stop_sequence from (select route_id, direction_id, max(stop_sequence) as stop_sequence, max(a.trip_id) as trip_id from stop_times inner join (SELECT route_id, direction_id, max(trip_id) as trip_id
  from trips group by route_id,direction_id) as a on stop_times.trip_id = a.trip_id group by route_id, direction_id) as b inner join stop_times on b.trip_id = stop_times.trip_id inner join stops on stop_times.stop_id = stops.stop_id where stop_times.stop_sequence = b.stop_sequence and stop_name = :destination order by route_id;";
  } else {
  $query = "select stop_name from (select route_id, direction_id, max(stop_sequence) as stop_sequence, max(a.trip_id) as trip_id from stop_times inner join (SELECT route_id, direction_id, max(trip_id) as trip_id
  from trips group by route_id,direction_id) as a on stop_times.trip_id = a.trip_id group by route_id, direction_id) as b inner join stop_times on b.trip_id = stop_times.trip_id inner join stops on stop_times.stop_id = stops.stop_id where stop_times.stop_sequence = b.stop_sequence group by stop_name order by stop_name;";
  }
  debug($query, "database");
  $query = $conn->prepare($query);
   
  //$query->bindParam(":service_periodA", $sidA);
  //$query->bindParam(":service_periodB", $sidB);
  if ($destination != "")
  $query->bindParam(":destination", $destination);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
  }
   
  function getRoutesBySuburb($suburb, $service_period = "") {
  if ($service_period == "")
  $service_period = service_period();
  $service_ids = service_ids($service_period);
  $sidA = $service_ids[0];
  $sidB = $service_ids[1];
   
  global $conn;
  $query = "SELECT DISTINCT service_id,trips.route_id,route_short_name,route_long_name
  FROM stop_times join trips on trips.trip_id = stop_times.trip_id
  join routes on trips.route_id = routes.route_id
  join stops on stops.stop_id = stop_times.stop_id
  WHERE stop_desc LIKE :suburb AND (service_id=:service_periodA OR service_id=:service_periodB)
  ORDER BY route_short_name";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":service_periodA", $sidA);
  $query->bindParam(":service_periodB", $sidB);
  $suburb = "%Suburb: %" . $suburb . "%";
  $query->bindParam(":suburb", $suburb);
  $query->execute();
   
  databaseError($conn->errorInfo());
   
  return $query->fetchAll();
  }
   
  function getRoutesNearby($lat, $lng, $limit = "", $distance = 500) {
  // if ($service_period == "")
  $service_period = service_period();
  $service_ids = service_ids($service_period);
  $sidA = $service_ids[0];
  $sidB = $service_ids[1];
  $limitSQL = "";
  if ($limit != "")
  $limitSQL = " LIMIT :limit ";
  global $conn;
  $query = "SELECT service_id,trips.route_id,trips.direction_id,route_short_name,route_long_name,min(stops.stop_id) as stop_id,
  min(ST_Distance(position, ST_GeographyFromText('SRID=4326;POINT($lng $lat)'), FALSE)) as distance
  FROM stop_times
  join trips on trips.trip_id = stop_times.trip_id
  join routes on trips.route_id = routes.route_id
  join stops on stops.stop_id = stop_times.stop_id
  WHERE (service_id=:service_periodA OR service_id=:service_periodB)
  AND ST_DWithin(position, ST_GeographyFromText('SRID=4326;POINT($lng $lat)'), :distance, FALSE)
  group by service_id,trips.route_id,trips.direction_id,route_short_name,route_long_name
  order by distance $limitSQL";
  debug($query, "database");
  $query = $conn->prepare($query);
  $query->bindParam(":service_periodA", $sidA);
  $query->bindParam(":service_periodB", $sidB);
  $query->bindParam(":distance", $distance);
  if ($limit != "")
  $query->bindParam(":limit", $limit);
  $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
  }