137 lines
3.9 KiB
SQL
137 lines
3.9 KiB
SQL
WITH base_data AS (
|
|
SELECT
|
|
service_id,
|
|
status,
|
|
timestamp,
|
|
date_trunc('hour', timestamp) as hr_ts,
|
|
date_trunc('day', timestamp) as day_ts
|
|
FROM status_records
|
|
WHERE timestamp >= NOW() - INTERVAL '60 days'
|
|
),
|
|
time_slots_minutes AS (
|
|
SELECT generate_series(
|
|
date_trunc('minute', now()) - interval '59 minutes',
|
|
date_trunc('minute', now()),
|
|
interval '1 minute'
|
|
) as slot
|
|
),
|
|
filled_minute_data AS (
|
|
SELECT
|
|
s.id as service_id,
|
|
ts.slot as timestamp,
|
|
COALESCE(MAX(bd.status), 3) as status
|
|
FROM time_slots_minutes ts
|
|
CROSS JOIN services s
|
|
LEFT JOIN base_data bd ON
|
|
date_trunc('minute', bd.timestamp) = ts.slot
|
|
AND bd.service_id = s.id
|
|
GROUP BY s.id, ts.slot
|
|
),
|
|
minute_agg AS (
|
|
SELECT
|
|
service_id,
|
|
json_agg(
|
|
json_build_object('timestamp', timestamp, 'status', status)
|
|
ORDER BY timestamp DESC
|
|
) as data
|
|
FROM filled_minute_data
|
|
GROUP BY service_id
|
|
),
|
|
time_slots_hours AS (
|
|
SELECT generate_series(
|
|
date_trunc('hour', now()) - interval '23 hours',
|
|
date_trunc('hour', now()),
|
|
interval '1 hour'
|
|
) as slot
|
|
),
|
|
filled_hours_data AS (
|
|
SELECT
|
|
s.id as service_id,
|
|
ts.slot as timestamp,
|
|
COALESCE(AVG(CASE WHEN bd.status = 1 THEN 1.0 WHEN bd.status = 3 THEN NULL ELSE 0.0 END), 3) as ratio
|
|
FROM time_slots_hours ts
|
|
CROSS JOIN services s
|
|
LEFT JOIN base_data bd ON
|
|
date_trunc('hour', bd.timestamp) = ts.slot
|
|
AND bd.service_id = s.id
|
|
GROUP BY s.id, ts.slot
|
|
),
|
|
hour_agg AS (
|
|
SELECT
|
|
service_id,
|
|
json_agg(
|
|
json_build_object(
|
|
'timestamp', timestamp,
|
|
'status', CASE
|
|
WHEN ratio = 3 THEN 3
|
|
WHEN ratio >= 0.95 THEN 1
|
|
WHEN ratio >= 0.5 THEN 2
|
|
ELSE 0
|
|
END
|
|
) ORDER BY timestamp DESC
|
|
) as data
|
|
FROM filled_hours_data
|
|
GROUP BY service_id
|
|
),
|
|
time_slots_days AS (
|
|
SELECT generate_series(
|
|
date_trunc('day', now()) - interval '59 days',
|
|
date_trunc('day', now()),
|
|
interval '1 day'
|
|
) as slot
|
|
),
|
|
filled_days_data AS (
|
|
SELECT
|
|
s.id as service_id,
|
|
ts.slot as timestamp,
|
|
COALESCE(
|
|
AVG(CASE WHEN bd.status = 1 THEN 1.0 WHEN bd.status = 3 THEN NULL ELSE 0.0 END),
|
|
3
|
|
) as ratio
|
|
FROM time_slots_days ts
|
|
CROSS JOIN services s
|
|
LEFT JOIN base_data bd ON
|
|
date_trunc('day', bd.timestamp) = ts.slot
|
|
AND bd.service_id = s.id
|
|
GROUP BY s.id, ts.slot
|
|
),
|
|
day_agg AS (
|
|
SELECT
|
|
service_id,
|
|
json_agg(
|
|
json_build_object(
|
|
'timestamp', timestamp,
|
|
'status', CASE
|
|
WHEN ratio = 3 THEN 3
|
|
WHEN ratio >= 0.98 THEN 1
|
|
WHEN ratio >= 0.5 THEN 2
|
|
ELSE 0
|
|
END
|
|
) ORDER BY timestamp DESC
|
|
) as data
|
|
FROM filled_days_data
|
|
GROUP BY service_id
|
|
)
|
|
SELECT
|
|
n.id as id, n.name, n.address, n.status, n.last_seen,
|
|
COALESCE(
|
|
jsonb_agg(
|
|
json_build_object(
|
|
'id', s.id,
|
|
'name', s.name,
|
|
'command', s.command,
|
|
'history', json_build_object(
|
|
'minute', COALESCE(ma.data, '[]'::json),
|
|
'hour', COALESCE(ha.data, '[]'::json),
|
|
'day', COALESCE(da.data, '[]'::json)
|
|
)
|
|
)
|
|
) FILTER (WHERE s.id IS NOT NULL),
|
|
'[]'::jsonb
|
|
) as services
|
|
FROM nodes n
|
|
LEFT JOIN services s ON n.id = s.node_id
|
|
LEFT JOIN minute_agg ma ON s.id = ma.service_id
|
|
LEFT JOIN hour_agg ha ON s.id = ha.service_id
|
|
LEFT JOIN day_agg da ON s.id = da.service_id
|
|
GROUP BY n.id; |