Port DB calls to PHP PDO
Port DB calls to PHP PDO

<?php <?php
if (php_uname('n') == "actbus-www") { if (php_uname('n') == "actbus-www") {
$conn = pg_connect("dbname=transitdata user=transitdata password=transitdata host=bus-main.lambdacomplex.org"); $conn = new PDO("pgsql:dbname=transitdata;user=transitdata;password=transitdata;host=bus-main.lambdacomplex.org");
} else if (isDebugServer()) { }
$conn = pg_connect("dbname=transitdata user=postgres password=snmc"); else if (isDebugServer()) {
} else { $conn = new PDO("pgsql:dbname=transitdata;user=postgres;password=snmc;host=localhost");
$conn = pg_connect("dbname=transitdata user=transitdata password=transitdata "); }
} else {
if (!$conn) { $conn = new PDO("pgsql:dbname=transitdata;user=transitdata;password=transitdata;host=localhost");
die("A database error occurred.\n"); }
} if (!$conn) {
  die("A database error occurred.\n");
function databaseError($errMsg) { }
die($errMsg); function databaseError($errMsg)
} {
  die($errMsg);
include('db/route-dao.inc.php'); }
include('db/trip-dao.inc.php'); include ('db/route-dao.inc.php');
include('db/stop-dao.inc.php'); include ('db/trip-dao.inc.php');
?> include ('db/stop-dao.inc.php');
  include ('db/servicealert-dao.inc.php');
  ?>
   
<?php <?php
if (isset($_REQUEST['firstLetter'])) { if (isset($_REQUEST['firstLetter'])) {
$firstLetter = filter_var($_REQUEST['firstLetter'], FILTER_SANITIZE_STRING); $firstLetter = filter_var($_REQUEST['firstLetter'], FILTER_SANITIZE_STRING);
} }
if (isset($_REQUEST['bysuburbs'])) { if (isset($_REQUEST['bysuburbs'])) {
$bysuburbs = true; $bysuburbs = true;
} }
if (isset($_REQUEST['bynumber'])) { if (isset($_REQUEST['bynumber'])) {
$bynumber = true; $bynumber = true;
} }
if (isset($_REQUEST['allstops'])) { if (isset($_REQUEST['allstops'])) {
$allstops = true; $allstops = true;
} }
if (isset($_REQUEST['nearby'])) { if (isset($_REQUEST['nearby'])) {
$nearby = true; $nearby = true;
} }
if (isset($_REQUEST['suburb'])) { if (isset($_REQUEST['suburb'])) {
$suburb = filter_var($_REQUEST['suburb'], FILTER_SANITIZE_STRING); $suburb = filter_var($_REQUEST['suburb'], FILTER_SANITIZE_STRING);
} }
$pageKey = filter_var($_REQUEST['pageKey'], FILTER_SANITIZE_NUMBER_INT); $pageKey = filter_var($_REQUEST['pageKey'], FILTER_SANITIZE_NUMBER_INT);
$lat = filter_var($_REQUEST['lat'], FILTER_SANITIZE_NUMBER_FLOAT, FILTER_FLAG_ALLOW_FRACTION); $lat = filter_var($_REQUEST['lat'], FILTER_SANITIZE_NUMBER_FLOAT, FILTER_FLAG_ALLOW_FRACTION);
$lon = filter_var($_REQUEST['lon'], FILTER_SANITIZE_NUMBER_FLOAT, FILTER_FLAG_ALLOW_FRACTION); $lon = filter_var($_REQUEST['lon'], FILTER_SANITIZE_NUMBER_FLOAT, FILTER_FLAG_ALLOW_FRACTION);
$max_distance = filter_var($_REQUEST['radius'], FILTER_SANITIZE_NUMBER_INT); $max_distance = filter_var($_REQUEST['radius'], FILTER_SANITIZE_NUMBER_INT);
if (isset($_REQUEST['numberSeries'])) { if (isset($_REQUEST['numberSeries'])) {
$numberSeries = filter_var($_REQUEST['numberSeries'], FILTER_SANITIZE_NUMBER_INT); $numberSeries = filter_var($_REQUEST['numberSeries'], FILTER_SANITIZE_NUMBER_INT);
} }
if (isset($_REQUEST['routeDestination'])) { if (isset($_REQUEST['routeDestination'])) {
$routeDestination = urldecode(filter_var($_REQUEST['routeDestination'], FILTER_SANITIZE_ENCODED)); $routeDestination = urldecode(filter_var($_REQUEST['routeDestination'], FILTER_SANITIZE_ENCODED));
} }
if (isset($_REQUEST['stopcode'])) { if (isset($_REQUEST['stopcode'])) {
$stopcode = filter_var($_REQUEST['stopcode'], FILTER_SANITIZE_STRING); $stopcode = filter_var($_REQUEST['stopcode'], FILTER_SANITIZE_STRING);
} }
if (isset($_REQUEST['stopids'])) { if (isset($_REQUEST['stopids'])) {
$stopids = explode(",", filter_var($_REQUEST['stopids'], FILTER_SANITIZE_STRING)); $stopids = explode(",", filter_var($_REQUEST['stopids'], FILTER_SANITIZE_STRING));
} }
if (isset($_REQUEST['tripid'])) { if (isset($_REQUEST['tripid'])) {
$tripid = filter_var($_REQUEST['tripid'], FILTER_SANITIZE_NUMBER_INT); $tripid = filter_var($_REQUEST['tripid'], FILTER_SANITIZE_NUMBER_INT);
} }
if (isset($_REQUEST['stopid'])) { if (isset($_REQUEST['stopid'])) {
$stopid = filter_var($_REQUEST['stopid'], FILTER_SANITIZE_NUMBER_INT); $stopid = filter_var($_REQUEST['stopid'], FILTER_SANITIZE_NUMBER_INT);
} }
if (isset($_REQUEST['stopid'])) { if (isset($_REQUEST['routeid'])) {
$routeid = filter_var($_REQUEST['routeid'], FILTER_SANITIZE_NUMBER_INT); $routeid = filter_var($_REQUEST['routeid'], FILTER_SANITIZE_NUMBER_INT);
} }
?> ?>
<?php <?php
$service_periods = Array( $service_periods = Array(
'sunday', 'sunday',
'saturday', 'saturday',
'weekday' 'weekday'
); );
function getServiceOverride() {  
global $conn;  
$query = "Select * from calendar_dates where date = '".date("Ymd")."' and exception_type = '1'";  
debug($query,"database");  
$result = pg_query($conn, $query);  
if (!$result) {  
databaseError(pg_result_error($result));  
return Array();  
}  
return pg_fetch_assoc($result);  
}  
function service_period() function service_period()
{ {
if (isset($_SESSION['service_period'])) return $_SESSION['service_period']; if (isset($_SESSION['service_period'])) return $_SESSION['service_period'];
$override = getServiceOverride(); $override = getServiceOverride();
if ($override['service_id']){ if ($override['service_id']){
return $override['service_id']; return $override['service_id'];
} }
   
switch (date('w')) { switch (date('w')) {
case 0: case 0:
return 'sunday'; return 'sunday';
case 6: case 6:
return 'saturday'; return 'saturday';
default: default:
return 'weekday'; return 'weekday';
} }
} }
function midnight_seconds() function midnight_seconds()
{ {
// from http://www.perturb.org/display/Perlfunc__Seconds_Since_Midnight.html // from http://www.perturb.org/display/Perlfunc__Seconds_Since_Midnight.html
if (isset($_SESSION['time'])) { if (isset($_SESSION['time'])) {
$time = strtotime($_SESSION['time']); $time = strtotime($_SESSION['time']);
return (date("G", $time) * 3600) + (date("i", $time) * 60) + date("s", $time); return (date("G", $time) * 3600) + (date("i", $time) * 60) + date("s", $time);
} }
return (date("G") * 3600) + (date("i") * 60) + date("s"); return (date("G") * 3600) + (date("i") * 60) + date("s");
} }
function midnight_seconds_to_time($seconds) function midnight_seconds_to_time($seconds)
{ {
if ($seconds > 0) { if ($seconds > 0) {
$midnight = mktime(0, 0, 0, date("n") , date("j") , date("Y")); $midnight = mktime(0, 0, 0, date("n") , date("j") , date("Y"));
return date("h:ia", $midnight + $seconds); return date("h:ia", $midnight + $seconds);
} }
else { else {
return ""; return "";
} }
} }
?> ?>
   
<?php <?php
function getRoute($routeID) function getRoute($routeID)
{ {
global $conn; global $conn;
$query = "Select * from routes where route_id = '$routeID' LIMIT 1"; $query = "Select * from routes where route_id = :routeID LIMIT 1";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":routeID", $routeID);
databaseError(pg_result_error($result)); $query->execute();
return Array(); if (!$query) {
} databaseError($conn->errorInfo());
return pg_fetch_assoc($result); return Array();
  }
  return $query->fetch(PDO::FETCH_ASSOC);
} }
function getRoutes() function getRoutes()
{ {
global $conn; global $conn;
$query = "Select * from routes order by route_short_name;"; $query = "Select * from routes order by route_short_name;";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->execute();
databaseError(pg_result_error($result)); if (!$query) {
return Array(); databaseError($conn->errorInfo());
} return Array();
return pg_fetch_all($result); }
  return $query->fetchAll();
} }
function getRoutesByNumber($routeNumber = "") function getRoutesByNumber($routeNumber = "")
{ {
global $conn; global $conn;
if ($routeNumber != "") { if ($routeNumber != "") {
$query = "Select distinct routes.route_id,routes.route_short_name,routes.route_long_name,service_id from routes join trips on trips.route_id = $query = "Select distinct routes.route_id,routes.route_short_name,routes.route_long_name,service_id from routes join trips on trips.route_id =
routes.route_id join stop_times on stop_times.trip_id = trips.trip_id where route_short_name = '$routeNumber' order by route_short_name;"; routes.route_id join stop_times on stop_times.trip_id = trips.trip_id where route_short_name = :routeNumber order by route_short_name;";
} }
else { else {
$query = "SELECT DISTINCT route_short_name from routes order by route_short_name"; $query = "SELECT DISTINCT route_short_name from routes order by route_short_name";
} }
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { if ($routeNumber != "") {
databaseError(pg_result_error($result)); $query->bindParam(":routeNumber", $routeNumber);
return Array(); }
} $query->execute();
return pg_fetch_all($result); if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
} }
function getRoutesByNumberSeries($routeNumberSeries = "") function getRoutesByNumberSeries($routeNumberSeries = "")
{ {
global $conn; global $conn;
if (strlen($routeNumberSeries) == 1) { if (strlen($routeNumberSeries) == 1) {
return getRoutesByNumber($routeNumberSeries); return getRoutesByNumber($routeNumberSeries);
} }
$seriesMin = substr($routeNumberSeries, 0, -1) . "0"; $seriesMin = substr($routeNumberSeries, 0, -1) . "0";
$seriesMax = substr($routeNumberSeries, 0, -1) . "9"; $seriesMax = substr($routeNumberSeries, 0, -1) . "9";
$query = "Select distinct routes.route_id,routes.route_short_name,routes.route_long_name,service_id from routes join trips on trips.route_id = $query = "Select distinct routes.route_id,routes.route_short_name,routes.route_long_name,service_id from routes join trips on trips.route_id =
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 order by route_short_name;"; 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;";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":seriesMin", $seriesMin);
databaseError(pg_result_error($result)); $query->bindParam(":seriesMax", $seriesMax);
return Array(); $routeNumberSeries = "% ".substr($routeNumberSeries, 0, -1)."%";
} $query->bindParam(":routeNumberSeries", $routeNumberSeries);
return pg_fetch_all($result); $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
} }
function getRouteNextTrip($routeID) function getRouteNextTrip($routeID)
{ {
global $conn; global $conn;
$query = "select * from routes join trips on trips.route_id = routes.route_id $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 join stop_times on stop_times.trip_id = trips.trip_id where
arrival_time > '" . current_time() . "' and routes.route_id = '$routeID' order by arrival_time > :currentTime and routes.route_id = :routeID order by
arrival_time limit 1"; arrival_time limit 1";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":currentTime", current_time());
databaseError(pg_result_error($result)); $query->bindParam(":routeID", $routeID);
return Array(); $query->execute();
} if (!$query) {
$r = pg_fetch_assoc($result); databaseError($conn->errorInfo());
  return Array();
  }
  $r = $query->fetch(PDO::FETCH_ASSOC);
   
// past last trip of the day special case // past last trip of the day special case
if (sizeof($r) == 0) { if (sizeof($r) < 16) {
$query = "select * from routes join trips on trips.route_id = routes.route_id $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' order by join stop_times on stop_times.trip_id = trips.trip_id where routes.route_id = :routeID order by
arrival_time DESC limit 1"; arrival_time DESC limit 1";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":routeID", $routeID);
databaseError(pg_result_error($result)); $query->execute();
  if (!$query) {
  databaseError($conn->errorInfo());
return Array(); return Array();
} }
$r = pg_fetch_assoc($result);  
  $r = $query->fetch(PDO::FETCH_ASSOC);
} }
return $r; return $r;
} }
function getTimeInterpolatedRouteAtStop($routeID, $stop_id) function getTimeInterpolatedRouteAtStop($routeID, $stop_id)
{ {
$nextTrip = getRouteNextTrip($routeID); $nextTrip = getRouteNextTrip($routeID);
if ($nextTrip['trip_id']) { if ($nextTrip['trip_id']) {
foreach (getTimeInterpolatedTrip($nextTrip['trip_id']) as $tripStop) { foreach (getTimeInterpolatedTrip($nextTrip['trip_id']) as $tripStop) {
if ($tripStop['stop_id'] == $stop_id) return $tripStop; if ($tripStop['stop_id'] == $stop_id) return $tripStop;
} }
} }
return Array(); return Array();
} }
function getRouteTrips($routeID) function getRouteTrips($routeID)
{ {
global $conn; global $conn;
$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 $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 routes.route_id = '$routeID' and stop_sequence = '1' order by join stop_times on stop_times.trip_id = trips.trip_id where routes.route_id = :routeID and stop_sequence = '1' order by
arrival_time "; arrival_time ";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":routeID", $routeID);
databaseError(pg_result_error($result)); $query->execute();
return Array(); if (!$query) {
} databaseError($conn->errorInfo());
return pg_fetch_all($result); return Array();
  }
  return $query->fetchAll();
} }
function getRoutesByDestination($destination = "", $service_period = "") function getRoutesByDestination($destination = "", $service_period = "")
{ {
global $conn; global $conn;
if ($service_period == "") $service_period = service_period(); if ($service_period == "") $service_period = service_period();
if ($destination != "") { if ($destination != "") {
$query = "SELECT DISTINCT trips.route_id,route_short_name,route_long_name, service_id $query = "SELECT DISTINCT trips.route_id,route_short_name,route_long_name, service_id
FROM stop_times join trips on trips.trip_id = FROM stop_times join trips on trips.trip_id =
stop_times.trip_id join routes on trips.route_id = routes.route_id stop_times.trip_id join routes on trips.route_id = routes.route_id
WHERE route_long_name = '$destination' AND service_id='$service_period' order by route_short_name"; WHERE route_long_name = :destination AND service_id=:service_period order by route_short_name";
} }
else { else {
$query = "SELECT DISTINCT route_long_name $query = "SELECT DISTINCT route_long_name
FROM stop_times join trips on trips.trip_id = FROM stop_times join trips on trips.trip_id =
stop_times.trip_id join routes on trips.route_id = routes.route_id stop_times.trip_id join routes on trips.route_id = routes.route_id
WHERE service_id='$service_period' order by route_long_name"; WHERE service_id= :service_period order by route_long_name";
} }
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":service_period", $service_period);
databaseError(pg_result_error($result)); if ($destination != "") $query->bindParam(":destination", $destination);
return Array(); $query->execute();
} if (!$query) {
return pg_fetch_all($result); databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
} }
function getRoutesBySuburb($suburb, $service_period = "") function getRoutesBySuburb($suburb, $service_period = "")
{ {
if ($service_period == "") $service_period = service_period(); if ($service_period == "") $service_period = service_period();
global $conn; global $conn;
$query = "SELECT DISTINCT service_id,trips.route_id,route_short_name,route_long_name $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 FROM stop_times join trips on trips.trip_id = stop_times.trip_id
join routes on trips.route_id = routes.route_id join routes on trips.route_id = routes.route_id
join stops on stops.stop_id = stop_times.stop_id join stops on stops.stop_id = stop_times.stop_id
WHERE zone_id LIKE '%$suburb;%' AND service_id='$service_period' ORDER BY route_short_name"; WHERE zone_id LIKE ':suburb AND service_id=:service_period ORDER BY route_short_name";
debug($query, "database"); debug($query, "database");
$result = pg_query($conn, $query); $query = $conn->prepare($query);
if (!$result) { $query->bindParam(":service_period", $service_period);
databaseError(pg_result_error($result)); $suburb = "%" . $suburb . ";%";
return Array(); $query->bindParam(":suburb", $suburb);
} $query->execute();
return pg_fetch_all($result); if (!$query) {
  databaseError($conn->errorInfo());
  return Array();
  }
  return $query->fetchAll();
} }
function getRoutesNearby($lat, $lng, $limit = "", $distance = 500) function getRoutesNearby($lat, $lng, $limit = "", $distance = 500)
{ {
if ($service_period == "") $service_period = service_period(); if ($service_period == "") $service_period = service_period();
if ($limit != "") $limit = " LIMIT $limit "; if ($limit != "") $limitSQL = " LIMIT :limit ";
global $conn; global $conn;
$query = "SELECT service_id,trips.route_id,route_short_name,route_long_name,min(stops.stop_id) as stop_id, $query = "SELECT service_id,trips.route_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 min(ST_Distance(position, ST_GeographyFromText('SRID=4326;POINT($lng $lat)'), FALSE)) as distance
FROM stop_times FROM stop_times
join trips on trips.trip_id = stop_times.trip_id join trips on trips.trip_id = stop_times.trip_id
join routes on trips.route_id = routes.route_id join routes on trips.route_id = routes.route_id
join stops on stops.stop_id = stop_times.stop_id join stops on stops.stop_id = stop_times.stop_id
WHERE service_id='$service_period' WHERE service_id=:service_period
AND ST_DWithin(position, ST_GeographyFromText('SRID=4326;POINT($lng $lat)'), $distance, FALSE) AND ST_DWithin(position, ST_GeographyFromText('SRID=4326;POINT($lng $lat)'), :distance, FALSE)
group by service_id,trips.route_id,route_short_name,route_long_name group by service_id,trips.route_id,route_short_name,route_long_name
order by distance $limit"; order by distance $limitSQL";
debug($que