fixes
This commit is contained in:
@@ -19,7 +19,7 @@ if (empty(array_diff_key($_GET, array('service' => '')))) {
|
|||||||
'county', county,
|
'county', county,
|
||||||
'state', state,
|
'state', state,
|
||||||
'outage', outagen,
|
'outage', outagen,
|
||||||
'lastchange', last_change,
|
'lastchange', last_change,
|
||||||
'cause', COALESCE(cause, ''),
|
'cause', COALESCE(cause, ''),
|
||||||
'area_geometry', ST_AsGeoJSON(COALESCE(realareageom, geom))::json
|
'area_geometry', ST_AsGeoJSON(COALESCE(realareageom, geom))::json
|
||||||
)
|
)
|
||||||
@@ -27,17 +27,17 @@ if (empty(array_diff_key($_GET, array('service' => '')))) {
|
|||||||
ORDER BY start_time ASC
|
ORDER BY start_time ASC
|
||||||
), '[]'::json)
|
), '[]'::json)
|
||||||
) as geojson
|
) as geojson
|
||||||
FROM newpower
|
FROM newpower
|
||||||
WHERE cwa = $1 AND active = true AND geom IS NOT NULL
|
WHERE cwa = $1 AND active = true AND geom IS NOT NULL
|
||||||
";
|
";
|
||||||
|
|
||||||
$result = pg_query_params($dbconn, $query, array('RLX'));
|
$result = pg_query_params($dbconn, $query, array('RLX'));
|
||||||
if ($result === false) {
|
if ($result === false) {
|
||||||
throw new Exception('Query failed: ' . pg_last_error());
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
}
|
}
|
||||||
|
|
||||||
$resultArray = pg_fetch_assoc($result);
|
$resultArray = pg_fetch_assoc($result);
|
||||||
|
|
||||||
if ($resultArray && $resultArray['geojson']) {
|
if ($resultArray && $resultArray['geojson']) {
|
||||||
echo $resultArray['geojson'];
|
echo $resultArray['geojson'];
|
||||||
} else {
|
} else {
|
||||||
@@ -51,6 +51,52 @@ if (empty(array_diff_key($_GET, array('service' => '')))) {
|
|||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// Get states boundaries
|
||||||
|
if (isset($_GET['states'])) {
|
||||||
|
try {
|
||||||
|
$query = "
|
||||||
|
SELECT jsonb_build_object(
|
||||||
|
'type', 'FeatureCollection',
|
||||||
|
'features', jsonb_agg(features.feature)
|
||||||
|
)
|
||||||
|
FROM (
|
||||||
|
SELECT jsonb_build_object(
|
||||||
|
'type', 'Feature',
|
||||||
|
'geometry', ST_AsGeoJSON(ST_Transform(geom, 4326))::jsonb,
|
||||||
|
'properties', to_jsonb(properties) - 'geom'
|
||||||
|
) AS feature
|
||||||
|
FROM (
|
||||||
|
SELECT *
|
||||||
|
FROM states
|
||||||
|
WHERE state IN ('WV', 'VA', 'KY', 'MD', 'PA', 'OH')
|
||||||
|
) AS properties
|
||||||
|
) AS features
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query($dbconn, $query);
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$resultArray = pg_fetch_all($result);
|
||||||
|
|
||||||
|
// Set proper JSON header and handle output
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
if ($resultArray && isset($resultArray[0]['jsonb_build_object'])) {
|
||||||
|
echo $resultArray[0]['jsonb_build_object'];
|
||||||
|
} else {
|
||||||
|
echo json_encode(['type' => 'FeatureCollection', 'features' => []]);
|
||||||
|
}
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(500);
|
||||||
|
echo json_encode(['error' => 'Query execution failed: ' . $e->getMessage()]);
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
// Get current county outages
|
// Get current county outages
|
||||||
if (isset($_GET['county'])) {
|
if (isset($_GET['county'])) {
|
||||||
try {
|
try {
|
||||||
@@ -58,16 +104,16 @@ if (isset($_GET['county'])) {
|
|||||||
WITH latest_fetch AS (
|
WITH latest_fetch AS (
|
||||||
SELECT MAX(fetch_time) as max_fetch_time FROM newcountyoutages
|
SELECT MAX(fetch_time) as max_fetch_time FROM newcountyoutages
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
n.county,
|
n.county,
|
||||||
n.state,
|
n.state,
|
||||||
n.outages as outage,
|
n.outages as outage,
|
||||||
n.fetch_time as time,
|
n.fetch_time as time,
|
||||||
n.served,
|
n.served,
|
||||||
CASE
|
CASE
|
||||||
WHEN n.served > 0 THEN ROUND(CAST((n.outages::FLOAT / n.served) * 100 AS NUMERIC), 2)
|
WHEN n.served > 0 THEN ROUND(CAST((n.outages::FLOAT / n.served) * 100 AS NUMERIC), 2)
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END as perout
|
END as perout
|
||||||
FROM newcountyoutages n, latest_fetch
|
FROM newcountyoutages n, latest_fetch
|
||||||
WHERE n.fetch_time = latest_fetch.max_fetch_time
|
WHERE n.fetch_time = latest_fetch.max_fetch_time
|
||||||
AND n.cwa = $1
|
AND n.cwa = $1
|
||||||
@@ -79,20 +125,394 @@ if (isset($_GET['county'])) {
|
|||||||
}
|
}
|
||||||
|
|
||||||
$results = pg_fetch_all($result) ?: [];
|
$results = pg_fetch_all($result) ?: [];
|
||||||
|
header('Content-Type: application/json');
|
||||||
echo json_encode($results);
|
echo json_encode($results);
|
||||||
|
|
||||||
pg_free_result($result);
|
pg_free_result($result);
|
||||||
} catch (Exception $e) {
|
} catch (Exception $e) {
|
||||||
|
header('Content-Type: application/json');
|
||||||
http_response_code(500);
|
http_response_code(500);
|
||||||
echo json_encode(['error' => 'Query execution failed: ' . $e->getMessage()]);
|
echo json_encode(['error' => 'Query execution failed: ' . $e->getMessage()]);
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
// Note: Other endpoints from the original powerapi.php can be migrated here as needed,
|
// Max county outages for a time range
|
||||||
// such as 'states', 'max', 'countyarchive', 'archivepoint', 'svr', 'svrpolys',
|
if (isset($_GET['max'])) {
|
||||||
// 'powerids', 'poweridsgeojson', and 'polygongeojson'.
|
if (isset($_GET['start']) && isset($_GET['end'])) {
|
||||||
// The queries would need to be updated to use the 'newpower' and 'newcountyoutages' tables
|
try {
|
||||||
// and their corresponding columns (e.g., start_time, geom, fetch_time).
|
$starttime = getParam('start');
|
||||||
|
$endtime = getParam('end');
|
||||||
|
|
||||||
|
$query = "
|
||||||
|
SELECT DISTINCT ON (county, state)
|
||||||
|
max(outage) as max_outage,
|
||||||
|
county,
|
||||||
|
state
|
||||||
|
FROM (
|
||||||
|
SELECT DISTINCT ON (county, state, fetch_time)
|
||||||
|
county,
|
||||||
|
state,
|
||||||
|
SUM(outages) as outage,
|
||||||
|
fetch_time as time,
|
||||||
|
SUM(served) as served
|
||||||
|
FROM newcountyoutages
|
||||||
|
WHERE fetch_time > $2
|
||||||
|
AND fetch_time < $3
|
||||||
|
AND cwa = $1
|
||||||
|
GROUP BY county, state, fetch_time
|
||||||
|
) as subquery
|
||||||
|
GROUP BY county, state
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query_params(
|
||||||
|
$dbconn,
|
||||||
|
$query,
|
||||||
|
['RLX', $starttime, $endtime]
|
||||||
|
);
|
||||||
|
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$results = [];
|
||||||
|
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
|
||||||
|
$results[] = $line;
|
||||||
|
}
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
echo json_encode($results);
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(500);
|
||||||
|
echo json_encode(['error' => 'Query execution failed: ' . $e->getMessage()]);
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
} else {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(400);
|
||||||
|
echo json_encode(['error' => 'Both start and end parameters are required']);
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Archive county outages for a time range
|
||||||
|
if (isset($_GET['countyarchive'])) {
|
||||||
|
if (isset($_GET['start']) && isset($_GET['end'])) {
|
||||||
|
try {
|
||||||
|
$starttime = getParam('start');
|
||||||
|
$endtime = getParam('end');
|
||||||
|
|
||||||
|
$query = "
|
||||||
|
SELECT DISTINCT ON (county, state, fetch_time)
|
||||||
|
county,
|
||||||
|
state,
|
||||||
|
SUM(outages) as outage,
|
||||||
|
fetch_time as time,
|
||||||
|
SUM(served) as served
|
||||||
|
FROM newcountyoutages
|
||||||
|
WHERE fetch_time > $9
|
||||||
|
AND fetch_time < $10
|
||||||
|
AND (cwa = $1 OR cwa = $2 OR cwa = $3 OR cwa = $4 OR cwa = $5 OR cwa = $6 OR cwa = $7 OR cwa = $8)
|
||||||
|
GROUP BY county, state, fetch_time
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query_params($dbconn, $query, ['RLX','JKL','ILN','PBZ','MRX','LWX','RNK','CTP',$starttime,$endtime]);
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$results = [];
|
||||||
|
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
|
||||||
|
$results[] = $line;
|
||||||
|
}
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
echo json_encode($results);
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(500);
|
||||||
|
echo json_encode(['error' => 'Query execution failed: ' . $e->getMessage()]);
|
||||||
|
if (isset($result)) {
|
||||||
|
pg_free_result($result);
|
||||||
|
}
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
} else {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(400);
|
||||||
|
echo json_encode(['error' => 'Both start and end parameters are required']);
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Archive point data for a time range
|
||||||
|
if (isset($_GET['archivepoint'])) {
|
||||||
|
try {
|
||||||
|
if (!isset($_GET['start']) || !isset($_GET['end'])) {
|
||||||
|
throw new Exception('Both start and end parameters are required');
|
||||||
|
}
|
||||||
|
|
||||||
|
$starttime = getParam('start');
|
||||||
|
$endtime = getParam('end');
|
||||||
|
|
||||||
|
$query = "
|
||||||
|
SELECT json_build_object(
|
||||||
|
'type', 'FeatureCollection',
|
||||||
|
'features', json_agg(
|
||||||
|
json_build_object(
|
||||||
|
'type', 'Feature',
|
||||||
|
'geometry', ST_AsGeoJSON(geom)::json,
|
||||||
|
'properties', json_build_object(
|
||||||
|
'time', start_time,
|
||||||
|
'county', county,
|
||||||
|
'state', state,
|
||||||
|
'outage', outagen,
|
||||||
|
'lastchange', last_change,
|
||||||
|
'cause', cause
|
||||||
|
)
|
||||||
|
)
|
||||||
|
ORDER BY start_time ASC
|
||||||
|
)
|
||||||
|
)
|
||||||
|
FROM newpower
|
||||||
|
WHERE cwa = $1
|
||||||
|
AND start_time > $2
|
||||||
|
AND last_change < $3
|
||||||
|
AND geom IS NOT NULL
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query_params($dbconn, $query, ['RLX', $starttime, $endtime]);
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$resultArray = pg_fetch_all($result);
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
if ($resultArray && isset($resultArray[0]['json_build_object'])) {
|
||||||
|
echo $resultArray[0]['json_build_object'];
|
||||||
|
} else {
|
||||||
|
echo json_encode(['type' => 'FeatureCollection', 'features' => []]);
|
||||||
|
}
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
$statusCode = strpos($e->getMessage(), 'required') !== false ? 400 : 500;
|
||||||
|
http_response_code($statusCode);
|
||||||
|
echo json_encode(['error' => $e->getMessage()]);
|
||||||
|
if (isset($result)) {
|
||||||
|
pg_free_result($result);
|
||||||
|
}
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Current severe weather warnings
|
||||||
|
if (@$_GET['svr'] == 'current') {
|
||||||
|
try {
|
||||||
|
$result = pg_query($dbconn,
|
||||||
|
"SELECT json_build_object('type', 'FeatureCollection','features', json_agg(json_build_object('type','Feature', 'geometry', ST_AsGeoJSON(nwspoly)::json,'properties',json_build_object('issue',issue,'end',endtime,'vtec',vtec,'type',warntype)))) FROM svr where issue < now() and endtime > now()") or die('Query failed: ' . pg_last_error());
|
||||||
|
$resultArray = pg_fetch_all($result);
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
if ($resultArray && isset($resultArray[0]['json_build_object'])) {
|
||||||
|
echo $resultArray[0]['json_build_object'];
|
||||||
|
} else {
|
||||||
|
echo json_encode(['type' => 'FeatureCollection', 'features' => []]);
|
||||||
|
}
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(500);
|
||||||
|
echo json_encode(['error' => 'Query execution failed: ' . $e->getMessage()]);
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Archive severe weather warnings
|
||||||
|
if (isset($_GET['svr']) && $_GET['svr'] === 'archive') {
|
||||||
|
try {
|
||||||
|
$result = null;
|
||||||
|
|
||||||
|
if (isset($_GET['start']) && isset($_GET['end'])) {
|
||||||
|
$starttime = getParam('start');
|
||||||
|
$endtime = getParam('end');
|
||||||
|
|
||||||
|
$query = "
|
||||||
|
SELECT json_build_object(
|
||||||
|
'type', 'FeatureCollection',
|
||||||
|
'features', json_agg(
|
||||||
|
json_build_object(
|
||||||
|
'type', 'Feature',
|
||||||
|
'geometry', ST_AsGeoJSON(nwspoly)::json,
|
||||||
|
'properties', json_build_object(
|
||||||
|
'issue', issue,
|
||||||
|
'end', endtime,
|
||||||
|
'vtec', vtec,
|
||||||
|
'type', warntype
|
||||||
|
)
|
||||||
|
)
|
||||||
|
)
|
||||||
|
)
|
||||||
|
FROM svr
|
||||||
|
WHERE issue > $1
|
||||||
|
AND endtime < $2
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query_params($dbconn, $query, [$starttime, $endtime]);
|
||||||
|
} elseif (!isset($_GET['start']) && !isset($_GET['end'])) {
|
||||||
|
$query = "
|
||||||
|
SELECT json_build_object(
|
||||||
|
'type', 'FeatureCollection',
|
||||||
|
'features', json_agg(
|
||||||
|
json_build_object(
|
||||||
|
'type', 'Feature',
|
||||||
|
'geometry', ST_AsGeoJSON(nwspoly)::json,
|
||||||
|
'properties', json_build_object(
|
||||||
|
'issue', issue,
|
||||||
|
'end', endtime,
|
||||||
|
'vtec', vtec,
|
||||||
|
'type', warntype
|
||||||
|
)
|
||||||
|
)
|
||||||
|
)
|
||||||
|
)
|
||||||
|
FROM svr
|
||||||
|
WHERE issue < NOW() - INTERVAL '24 hours'
|
||||||
|
AND endtime > NOW() - INTERVAL '24 hours'
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query($dbconn, $query);
|
||||||
|
} else {
|
||||||
|
throw new Exception('Both start and end parameters are required together');
|
||||||
|
}
|
||||||
|
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$resultArray = pg_fetch_all($result);
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
if ($resultArray && isset($resultArray[0]['json_build_object'])) {
|
||||||
|
echo $resultArray[0]['json_build_object'];
|
||||||
|
} else {
|
||||||
|
echo json_encode(['type' => 'FeatureCollection', 'features' => []]);
|
||||||
|
}
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
if (isset($result)) {
|
||||||
|
pg_free_result($result);
|
||||||
|
}
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
$statusCode = strpos($e->getMessage(), 'required') !== false ? 400 : 500;
|
||||||
|
http_response_code($statusCode);
|
||||||
|
echo json_encode(['error' => $e->getMessage()]);
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Severe weather warning polygons
|
||||||
|
if (isset($_GET['svrpolys'])) {
|
||||||
|
try {
|
||||||
|
$query = "
|
||||||
|
SELECT
|
||||||
|
vtec,
|
||||||
|
outagesvalid,
|
||||||
|
polygonpop,
|
||||||
|
outagesbuffer,
|
||||||
|
lsrids
|
||||||
|
FROM svr
|
||||||
|
WHERE EXTRACT(EPOCH FROM (CURRENT_TIMESTAMP - endtime)) / 60 / 60 / 24 < 60
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query($dbconn, $query);
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$results = [];
|
||||||
|
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
|
||||||
|
$results[] = $line;
|
||||||
|
}
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
echo json_encode($results);
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
if (isset($result)) {
|
||||||
|
pg_free_result($result);
|
||||||
|
}
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
http_response_code(500);
|
||||||
|
echo json_encode(['error' => $e->getMessage()]);
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Power outage details by IDs
|
||||||
|
if (isset($_GET['powerids'])) {
|
||||||
|
try {
|
||||||
|
$powerids = $_GET['powerids'];
|
||||||
|
|
||||||
|
// Validate input exists and isn't empty
|
||||||
|
if (empty($powerids)) {
|
||||||
|
throw new Exception('No power IDs provided');
|
||||||
|
}
|
||||||
|
|
||||||
|
// Convert comma-separated string to array and sanitize
|
||||||
|
$poweridArray = explode(',', $powerids);
|
||||||
|
$sanitizedIds = array_filter(array_map('intval', $poweridArray));
|
||||||
|
|
||||||
|
if (empty($sanitizedIds)) {
|
||||||
|
throw new Exception('Invalid power ID format');
|
||||||
|
}
|
||||||
|
|
||||||
|
// Prepare placeholders for the query
|
||||||
|
$placeholders = implode(',', array_map(function($i) { return '$' . $i; }, range(1, count($sanitizedIds))));
|
||||||
|
|
||||||
|
$query = "
|
||||||
|
SELECT
|
||||||
|
lat,
|
||||||
|
lon,
|
||||||
|
last_change,
|
||||||
|
start_time,
|
||||||
|
peakoutage,
|
||||||
|
cause,
|
||||||
|
lsrtime,
|
||||||
|
lsrref,
|
||||||
|
(lsrtime AT TIME ZONE 'America/New_York')::timestamp as lsrlocal
|
||||||
|
FROM newpower
|
||||||
|
WHERE id IN ($placeholders)
|
||||||
|
";
|
||||||
|
|
||||||
|
$result = pg_query_params($dbconn, $query, $sanitizedIds);
|
||||||
|
if ($result === false) {
|
||||||
|
throw new Exception('Query failed: ' . pg_last_error());
|
||||||
|
}
|
||||||
|
|
||||||
|
$results = pg_fetch_all($result) ?: [];
|
||||||
|
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
echo json_encode($results);
|
||||||
|
|
||||||
|
pg_free_result($result);
|
||||||
|
} catch (Exception $e) {
|
||||||
|
if (isset($result)) {
|
||||||
|
pg_free_result($result);
|
||||||
|
}
|
||||||
|
header('Content-Type: application/json');
|
||||||
|
$statusCode = strpos($e->getMessage(), 'Invalid') !== false ? 400 : 500;
|
||||||
|
http_response_code($statusCode);
|
||||||
|
echo json_encode(['error' => $e->getMessage()]);
|
||||||
|
exit;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
pg_close($dbconn);
|
pg_close($dbconn);
|
||||||
?>
|
?>
|
||||||
Reference in New Issue
Block a user