Files
test/php/nws.php
2025-12-09 14:10:02 +00:00

385 lines
13 KiB
PHP

<?php
require_once __DIR__ . '/common.php';
$dbconn = getDBConnection();
//no gets, current point outage info
if(empty(array_diff_key($_GET, array('service' => '')))) {
$query = "SELECT * FROM nws order by lastupdate asc";
$result = pg_query($query) or die('Query failed: ' . pg_last_error());
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
$array[] = $line;
}
echo json_encode($array);
pg_free_result($result);
}
if (isset($_GET['officestats11'])) {
// Get all unique lastupdate dates from the database
$date_query = "SELECT DISTINCT DATE(lastupdate) as unique_date
FROM nws
WHERE status = 'active'
AND office ~ 'WFO'
ORDER BY unique_date ASC"; // Changed from DESC to ASC
$date_result = pg_query($dbconn, $date_query)
or die('Date query failed: ' . pg_last_error());
$datetime_points = [];
while ($row = pg_fetch_array($date_result, null, PGSQL_ASSOC)) {
$dt = DateTime::createFromFormat('Y-m-d', $row['unique_date']);
$dt->setTime(23, 59, 59);
$datetime_points[] = $dt->format('Y-m-d H:i:s');
}
pg_free_result($date_result);
if (empty($datetime_points)) {
echo json_encode(['error' => 'No valid datetime points found in database']);
exit;
}
// Debug: Log the datetime points
error_log("Processed datetime points: " . implode(', ', $datetime_points));
$query = "WITH latest_records AS (
SELECT *,
ROW_NUMBER() OVER (PARTITION BY personid ORDER BY ABS(EXTRACT(EPOCH FROM (lastupdate - CAST($1 AS TIMESTAMP)))) ASC) AS rn
FROM nws
WHERE status = 'active'
AND lastupdate <= CAST($1 AS TIMESTAMP) + INTERVAL '1 day'
AND lastupdate >= CAST($1 AS TIMESTAMP) - INTERVAL '3 days'
AND office ~ 'WFO'
),
otitle_counts AS (
SELECT
office,
otitle,
COUNT(*) AS otitle_count
FROM latest_records
WHERE rn = 1
GROUP BY office, otitle
)
SELECT
lr.office,
COUNT(DISTINCT lr.personid) AS unique_person_count,
(SELECT ARRAY_AGG(json_obj ORDER BY json_obj->>'otitle' ASC)
FROM (SELECT DISTINCT jsonb_build_object(
'otitle', tc2.otitle,
'count', tc2.otitle_count
) AS json_obj
FROM otitle_counts tc2
WHERE tc2.office = lr.office) AS subquery
) AS title_counts_array
FROM latest_records lr
WHERE lr.rn = 1
GROUP BY lr.office
ORDER BY unique_person_count DESC";
$results_array = [];
// Execute query for each unique datetime
foreach ($datetime_points as $datetime) {
$result = pg_query_params($dbconn, $query, array($datetime))
or die('Query failed: ' . pg_last_error());
$office_data = [];
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
$office_data[] = $line;
}
// Store results with the datetime used
$results_array[] = [
'provided_datetime' => $datetime,
'data' => $office_data
];
pg_free_result($result);
}
// Debug: Log before output
error_log("Final results: " . json_encode($results_array));
// Return JSON encoded results
echo json_encode($results_array);
}
if (isset($_GET['officestats'])) {
if (isset($_GET['datetime'])) {
// Expecting datetime as comma-separated dates or JSON array
$input_dates = is_array($_GET['datetime'])
? $_GET['datetime']
: explode(',', $_GET['datetime']);
// Process each date and set to end of day
$input_dates = array_unique($input_dates);
$input_dates = array_values($input_dates);
$datetime_points = [];
foreach ($input_dates as $date) {
$dt = DateTime::createFromFormat('m-d-Y', trim($date));
if ($dt === false) {
error_log("Invalid date skipped: " . trim($date));
continue;
}
$dt->setTime(23, 59, 59);
$datetime_points[] = $dt->format('Y-m-d H:i:s');
}
// Ensure uniqueness and reindex
$datetime_points = array_unique($datetime_points);
$datetime_points = array_values($datetime_points);
// Debug: Log the datetime points
error_log("Processed datetime points: " . implode(', ', $datetime_points));
if (empty($datetime_points)) {
echo json_encode(['error' => 'No valid datetime points provided']);
exit;
}
$query = "WITH latest_records AS (
SELECT *,
ROW_NUMBER() OVER (PARTITION BY personid ORDER BY ABS(EXTRACT(EPOCH FROM (lastupdate - CAST($1 AS TIMESTAMP)))) ASC) AS rn
FROM nws
WHERE status = 'active'
AND lastupdate <= CAST($1 AS TIMESTAMP) + INTERVAL '1 day'
AND lastupdate >= CAST($1 AS TIMESTAMP) - INTERVAL '3 days'
AND office ~ 'WFO'
),
otitle_counts AS (
SELECT
office,
otitle,
COUNT(*) AS otitle_count
FROM latest_records
WHERE rn = 1
GROUP BY office, otitle
)
SELECT
lr.office,
COUNT(DISTINCT lr.personid) AS unique_person_count,
(SELECT ARRAY_AGG(json_obj ORDER BY json_obj->>'otitle' ASC)
FROM (SELECT DISTINCT jsonb_build_object(
'otitle', tc2.otitle,
'count', tc2.otitle_count
) AS json_obj
FROM otitle_counts tc2
WHERE tc2.office = lr.office) AS subquery
) AS title_counts_array
FROM latest_records lr
WHERE lr.rn = 1
GROUP BY lr.office
ORDER BY unique_person_count DESC";
$results_array = [];
// Execute query for each provided datetime
foreach ($datetime_points as $datetime) {
$result = pg_query_params($dbconn, $query, array($datetime))
or die('Query failed: ' . pg_last_error());
$office_data = [];
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
$office_data[] = $line;
}
// Store results with the datetime used
$results_array[] = [
'provided_datetime' => $datetime,
'data' => $office_data
];
pg_free_result($result);
}
// Debug: Log before output
error_log("Final results: " . json_encode($results_array));
// Return JSON encoded results
echo json_encode($results_array);
}
}
if (isset($_GET['regionstats'])) {
if (isset($_GET['datetime'])) {
// Expecting datetime as comma-separated dates or JSON array
$input_dates = is_array($_GET['datetime'])
? $_GET['datetime']
: explode(',', $_GET['datetime']);
// Process each date and set to end of day
$input_dates = array_unique($input_dates);
$input_dates = array_values($input_dates);
$datetime_points = [];
foreach ($input_dates as $date) {
$dt = DateTime::createFromFormat('m-d-Y', trim($date));
if ($dt === false) {
error_log("Invalid date skipped: " . trim($date));
continue;
}
$dt->setTime(23, 59, 59);
$datetime_points[] = $dt->format('Y-m-d H:i:s');
}
// Ensure uniqueness and reindex
$datetime_points = array_unique($datetime_points);
$datetime_points = array_values($datetime_points);
// Debug: Log the datetime points
error_log("Processed datetime points: " . implode(', ', $datetime_points));
if (empty($datetime_points)) {
echo json_encode(['error' => 'No valid datetime points provided']);
exit;
}
$query = "WITH latest_records AS (
SELECT *,
ROW_NUMBER() OVER (PARTITION BY personid ORDER BY ABS(EXTRACT(EPOCH FROM (lastupdate - CAST($1 AS TIMESTAMP)))) ASC) AS rn,
SUBSTRING(office FROM 'NWS/([EWPASC]R)') AS region
FROM nws
WHERE lastupdate <= CAST($1 AS TIMESTAMP) + INTERVAL '1 day' - INTERVAL '1 second'
AND lastupdate >= CAST($1 AS TIMESTAMP) - INTERVAL '3 days'
AND office ~ 'NWS/[EWPASC]R'
and status = 'active'
),
otitle_counts AS (
SELECT
region,
otitle,
COUNT(*) AS otitle_count
FROM latest_records
WHERE rn = 1
GROUP BY region, otitle
)
SELECT
lr.region,
COUNT(DISTINCT lr.personid) AS unique_person_count,
(SELECT ARRAY_AGG(json_obj ORDER BY json_obj->>'otitle' ASC)
FROM (SELECT DISTINCT jsonb_build_object(
'otitle', tc2.otitle,
'count', tc2.otitle_count
) AS json_obj
FROM otitle_counts tc2
WHERE tc2.region = lr.region) AS subquery
) AS title_counts_array
FROM latest_records lr
WHERE lr.rn = 1
GROUP BY lr.region
ORDER BY unique_person_count DESC";
$results_array = [];
// Execute query for each provided datetime
foreach ($datetime_points as $datetime) {
$result = pg_query_params($dbconn, $query, array($datetime))
or die('Query failed: ' . pg_last_error());
$office_data = [];
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
$office_data[] = $line;
}
// Store results with the datetime used
$results_array[] = [
'provided_datetime' => $datetime,
'data' => $office_data
];
pg_free_result($result);
}
// Debug: Log before output
//error_log("Final results: " . json_encode($results_array));
// Return JSON encoded results
echo json_encode($results_array);
}
}
if (isset($_GET['drilldown'])) {
if (isset($_GET['datetime'])) {
// Expecting datetime as comma-separated dates or JSON array
$input_dates = is_array($_GET['datetime'])
? $_GET['datetime']
: explode(',', $_GET['datetime']);
// Process each date and set to end of day
$datetime_points = [];
foreach ($input_dates as $date) {
// Specify the exact format of your input date string
$dt = DateTime::createFromFormat('m-d-Y', trim($date)); // Adjust format as needed
if ($dt === false) {
// Handle invalid date
continue;
}
$dt->setTime(23, 59, 59);
$datetime_points[] = $dt->format('Y-m-d H:i:s');
}
$datetime_points = array_unique($datetime_points);
$datetime_points = array_values($datetime_points);
$query = "WITH latest_records AS (
SELECT *,
ROW_NUMBER() OVER (PARTITION BY personid ORDER BY lastupdate DESC) AS rn
FROM nws
WHERE status = 'active'
AND lastupdate <= $1
),
otitle_counts AS (
SELECT
office,
otitle,
COUNT(*) AS otitle_count
FROM latest_records
WHERE rn = 1
GROUP BY office, otitle
)
SELECT
lr.office,
COUNT(DISTINCT lr.personid) AS unique_person_count,
(SELECT ARRAY_AGG(json_obj ORDER BY json_obj->>'otitle' ASC)
FROM (SELECT DISTINCT jsonb_build_object(
'otitle', tc2.otitle,
'count', tc2.otitle_count
) AS json_obj
FROM otitle_counts tc2
WHERE tc2.office = lr.office) AS subquery
) AS title_counts_array
FROM latest_records lr
WHERE lr.rn = 1
GROUP BY lr.office
ORDER BY unique_person_count DESC";
$results_array = [];
// Execute query for each provided datetime
foreach ($datetime_points as $datetime) {
$result = pg_query_params($dbconn, $query, array($datetime))
or die('Query failed: ' . pg_last_error());
$office_data = [];
while ($line = pg_fetch_array($result, null, PGSQL_ASSOC)) {
$office_data[] = $line;
}
// Store results with the datetime used
$results_array[] = [
'provided_datetime' => $datetime,
'data' => $office_data
];
pg_free_result($result);
}
// Return JSON encoded results
echo json_encode($results_array);
}
}
// Close database connection when needed
if (isset($dbconn)) {
pg_close($dbconn);
}
?>