Cohort overlay
Relative time 0:00 represents the oldest point in the selected window. Hover to see bucket values and sample counts.
setTimezone($tz); $todayShiftStart = $localized->setTime(5, 0, 0); if ($localized < $todayShiftStart) { $windowEnd = $todayShiftStart->modify('-1 day'); } else { $windowEnd = $todayShiftStart; } $windowStart = $windowEnd->sub(new DateInterval('PT' . $durationHours . 'H')); return [$windowStart, $windowEnd]; } /** * @param mixed $value Interval from user input. */ function sanitizeInterval($value): int { $interval = (int) ($value ?? 15); $allowed = [5, 15, 30, 60]; if (!in_array($interval, $allowed, true)) { return 15; } return $interval; } function sanitizeWindowHours($value, array $allowed, int $fallback): int { $candidate = (int) ($value ?? 0); if (!in_array($candidate, $allowed, true)) { return $fallback; } return $candidate; } function alignToInterval(DateTimeImmutable $dateTime, int $interval, DateTimeZone $tz): DateTimeImmutable { $localized = $dateTime->setTimezone($tz); $minute = (int) $localized->format('i'); $second = (int) $localized->format('s'); $adjustMinutes = $minute % $interval; if ($adjustMinutes > 0) { $localized = $localized->modify(sprintf('-%d minutes', $adjustMinutes)); } if ($second > 0) { $localized = $localized->modify(sprintf('-%d seconds', $second)); } return $localized; } function minutesToLabel(int $minutes): string { $hours = intdiv($minutes, 60); $remaining = $minutes % 60; return sprintf('%02d:%02d', $hours, $remaining); } function buildCohortTimeline(int $interval, int $durationHours): array { $timeline = []; $maxMinutes = $durationHours * 60; for ($offset = 0; $offset < $maxMinutes; $offset += $interval) { $timeline[] = [ 'offset' => $offset, 'label' => minutesToLabel($offset), ]; } return $timeline; } function formatDateTime(DateTimeImmutable $dateTime): string { return $dateTime->format('Y-m-d H:i:s'); } function fetchBestDayDefinition(PDO $pdo, string $tag, DateTimeZone $tz, int $durationHours): ?array { $durationDays = max(1, (int) round($durationHours / 24)); $lookbackDays = 60; $minimumSamples = 12 * $durationDays; $lookbackWindowDays = $lookbackDays + $durationDays; $sql = " WITH shift_windows AS ( SELECT CAST(DATEADD(HOUR, -5, h.TimeStamp) AS date) AS shift_date, SUM(CAST(h.Value AS float)) AS sum_value, COUNT(*) AS sample_count FROM dbo.historicaldata AS h INNER JOIN dbo.id_names AS n ON h.ID = n.idnumber WHERE n.name = ? AND h.TimeStamp >= DATEADD(DAY, -CAST(? AS int), GETDATE()) GROUP BY CAST(DATEADD(HOUR, -5, h.TimeStamp) AS date) ), ordered AS ( SELECT shift_date, sum_value, sample_count, ROW_NUMBER() OVER (ORDER BY shift_date) AS rn FROM shift_windows ), rolling AS ( SELECT o.shift_date AS window_start_date, SUM(w.sum_value) AS total_sum_value, SUM(w.sample_count) AS total_sample_count, COUNT(DISTINCT w.rn) AS shifts_in_window FROM ordered AS o JOIN ordered AS w ON w.rn BETWEEN o.rn AND o.rn + (CAST(? AS int) - 1) GROUP BY o.shift_date ) SELECT TOP 1 window_start_date, total_sum_value / NULLIF(total_sample_count, 0) AS avg_value, total_sample_count FROM rolling WHERE shifts_in_window = CAST(? AS int) AND total_sample_count >= ? ORDER BY avg_value DESC; "; $stmt = $pdo->prepare($sql); $stmt->execute([ $tag, $lookbackWindowDays, $durationDays, $durationDays, $minimumSamples, ]); $row = $stmt->fetch(PDO::FETCH_ASSOC); if (!$row) { return null; } $startDate = DateTimeImmutable::createFromFormat('Y-m-d', (string) $row['window_start_date'], $tz); if (!$startDate instanceof DateTimeImmutable) { return null; } $start = $startDate->setTime(5, 0, 0); $end = $start->add(new DateInterval('PT' . $durationHours . 'H')); return [ 'label' => sprintf('Best %d-hour window (%s)', $durationHours, $start->format('M j, Y')), 'start' => $start, 'end' => $end, 'score' => (float) $row['avg_value'], 'sample_count' => (int) $row['total_sample_count'], ]; } function fetchCohortSeries( PDO $pdo, string $tag, DateTimeImmutable $start, DateTimeImmutable $end, int $interval, DateTimeZone $tz ): array { if ($end <= $start) { return [ 'points' => [], 'stats' => null, 'expectedBuckets' => 0, ]; } $durationMinutes = max(0, (int) floor(($end->getTimestamp() - $start->getTimestamp()) / 60)); $bucketExpr = sprintf( 'DATEADD(MINUTE, DATEDIFF(MINUTE, 0, h.TimeStamp) / %d * %d, 0)', $interval, $interval ); $sql = " WITH bucketed AS ( SELECT {$bucketExpr} AS bucket_start, AVG(CAST(h.Value AS float)) AS avg_value, COUNT(*) AS samples FROM dbo.historicaldata AS h INNER JOIN dbo.id_names AS n ON h.ID = n.idnumber WHERE n.name = ? AND h.TimeStamp >= ? AND h.TimeStamp < ? GROUP BY {$bucketExpr} ) SELECT CONVERT(varchar(19), bucket_start, 120) AS bucket_start_string, avg_value, samples FROM bucketed ORDER BY bucket_start ASC; "; $stmt = $pdo->prepare($sql); $stmt->execute([ $tag, $start->format('Y-m-d H:i:s'), $end->format('Y-m-d H:i:s'), ]); $rows = $stmt->fetchAll(PDO::FETCH_ASSOC); $points = []; $values = []; $totalSamples = 0; foreach ($rows as $row) { $bucketStart = DateTimeImmutable::createFromFormat( 'Y-m-d H:i:s', (string) $row['bucket_start_string'], $tz ); if (!$bucketStart instanceof DateTimeImmutable) { continue; } $offsetMinutes = (int) floor(($bucketStart->getTimestamp() - $start->getTimestamp()) / 60); if ($offsetMinutes < 0 || $offsetMinutes >= $durationMinutes) { continue; } $value = $row['avg_value'] !== null ? (float) $row['avg_value'] : null; $samples = (int) $row['samples']; if ($value !== null) { $values[] = $value; } $totalSamples += $samples; $points[] = [ 'offset' => $offsetMinutes, 'label' => minutesToLabel($offsetMinutes), 'value' => $value, 'samples' => $samples, 'bucket_start' => $bucketStart->format('Y-m-d H:i:s'), ]; } $expectedBuckets = $interval > 0 ? (int) floor($durationMinutes / $interval) : 0; $stats = calculateStats($values, $interval, $totalSamples, $expectedBuckets); return [ 'points' => $points, 'stats' => $stats, 'expectedBuckets' => $expectedBuckets, ]; } function calculateStats(array $values, int $interval, int $totalSamples, int $expectedBuckets): ?array { $count = count($values); if ($count === 0) { return null; } $sum = array_sum($values); $average = $sum / $count; $minimum = min($values); $maximum = max($values); $last = end($values); $variance = 0.0; foreach ($values as $value) { $variance += ($value - $average) * ($value - $average); } $stdDeviation = $count > 0 ? sqrt($variance / $count) : 0.0; $integral = $sum * ($interval / 60); $coverage = $expectedBuckets > 0 ? ($count / $expectedBuckets) * 100 : 0.0; return [ 'count' => $count, 'avg' => $average, 'min' => $minimum, 'max' => $maximum, 'last' => $last, 'stddev' => $stdDeviation, 'integral' => $integral, 'coverage' => $coverage, 'interval' => $interval, 'samples' => $totalSamples, 'expected_buckets' => $expectedBuckets, ]; } try { $pdo = new PDO( "sqlsrv:Server=$servername;Database=$dbname", $username, $password, [ PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION, PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC, ] ); } catch (PDOException $e) { if (isset($_POST['action'])) { header('Content-Type: application/json'); echo json_encode([ 'success' => false, 'error' => 'Database connection failed: ' . $e->getMessage(), ]); exit; } die('Connection failed: ' . $e->getMessage()); } if (isset($_POST['action'])) { ob_clean(); header('Content-Type: application/json'); try { switch ($_POST['action']) { case 'get_tags': $stmt = $pdo->prepare( "SELECT DISTINCT name FROM dbo.id_names WHERE name IS NOT NULL AND name <> '' ORDER BY name" ); $stmt->execute(); $tags = $stmt->fetchAll(PDO::FETCH_COLUMN); echo json_encode([ 'success' => true, 'tags' => $tags, ]); break; case 'get_cohort_data': $tag = trim((string) ($_POST['tag'] ?? '')); if ($tag === '') { throw new RuntimeException('Select at least one historian tag.'); } $interval = sanitizeInterval($_POST['interval'] ?? 15); $windowHours = sanitizeWindowHours( $_POST['window_hours'] ?? $defaultWindowHours, $windowOptions, $defaultWindowHours ); $cohortsRaw = $_POST['cohorts'] ?? '[]'; if (is_string($cohortsRaw)) { $decoded = json_decode($cohortsRaw, true); if (json_last_error() !== JSON_ERROR_NONE) { throw new RuntimeException('Invalid cohort payload: ' . json_last_error_msg()); } } else { $decoded = $cohortsRaw; } $allowedCohorts = ['current', 'previous_week', 'best_day']; $cohortKeys = array_values( array_intersect( $allowedCohorts, is_array($decoded) ? $decoded : [] ) ); if (empty($cohortKeys)) { $cohortKeys = $allowedCohorts; } if (!in_array('current', $cohortKeys, true)) { $cohortKeys[] = 'current'; } $now = new DateTimeImmutable('now', $appTimeZone); [$shiftStart, $shiftEnd] = getCurrentShiftWindow($now, $appTimeZone, $windowHours); $currentEnd = alignToInterval($shiftEnd, $interval, $appTimeZone); $currentStart = $currentEnd->sub(new DateInterval('PT' . $windowHours . 'H')); $definitions = []; $infoMessages = []; foreach ($cohortKeys as $key) { switch ($key) { case 'current': $definitions['current'] = [ 'label' => sprintf('Current %d hours', $windowHours), 'start' => $currentStart, 'end' => $currentEnd, ]; break; case 'previous_week': $definitions['previous_week'] = [ 'label' => 'Same window last week', 'start' => $currentStart->sub(new DateInterval('P7D')), 'end' => $currentEnd->sub(new DateInterval('P7D')), ]; break; case 'best_day': $bestDefinition = fetchBestDayDefinition($pdo, $tag, $appTimeZone, $windowHours); if ($bestDefinition !== null) { $definitions['best_day'] = $bestDefinition; if (!empty($bestDefinition['score'])) { $infoMessages[] = sprintf( 'Best %d-hour window average was %.2f across %d samples.', $windowHours, $bestDefinition['score'], $bestDefinition['sample_count'] ); } } else { $infoMessages[] = 'Best window cohort unavailable for the selected tag.'; } break; } } $timeline = buildCohortTimeline($interval, $windowHours); $infoMessages[] = sprintf( 'Comparing a %d-hour window with %d-minute buckets.', $windowHours, $interval ); $cohorts = []; foreach ($definitions as $key => $definition) { $series = fetchCohortSeries( $pdo, $tag, $definition['start'], $definition['end'], $interval, $appTimeZone ); $warnings = []; if ($series['stats'] === null) { $warnings[] = 'No historian data found for this cohort window.'; } elseif ($series['stats']['coverage'] < 70) { $warnings[] = sprintf( 'Only %.1f%% of expected buckets populated.', $series['stats']['coverage'] ); } $cohorts[] = [ 'key' => $key, 'label' => $definition['label'], 'start' => formatDateTime($definition['start']), 'end' => formatDateTime($definition['end']), 'points' => $series['points'], 'stats' => $series['stats'], 'warnings' => $warnings, ]; } if (empty($cohorts)) { throw new RuntimeException('No cohorts could be generated for the requested tag.'); } echo json_encode([ 'success' => true, 'tag' => $tag, 'intervalMinutes' => $interval, 'windowHours' => $windowHours, 'timeline' => $timeline, 'cohorts' => $cohorts, 'messages' => $infoMessages, 'generatedAt' => formatDateTime($currentEnd), ]); break; default: throw new RuntimeException('Unsupported action.'); } } catch (Throwable $exception) { echo json_encode([ 'success' => false, 'error' => $exception->getMessage(), ]); } exit; } require __DIR__ . '/../includes/layout/header.php'; ?>
Resample the current operating window and stack it against historical cohorts to spot changes in trajectory, stability, and peaks.
Choose a historian tag to plot. The latest window will line up against the cohorts you enable.
Pick how many hours to include in the active run and matched cohorts.
Compare the active run to one or more historical slices.
All cohorts are resampled to a common cadence so the comparison stays apples-to-apples.
Relative time 0:00 represents the oldest point in the selected window. Hover to see bucket values and sample counts.
Key metrics across each cohort using the shared cadence.