v1.0 with SW PWA enabled
This commit is contained in:
149
backend/sql/retrieve_node_list.sql
Normal file
149
backend/sql/retrieve_node_list.sql
Normal file
@ -0,0 +1,149 @@
|
||||
WITH base_data AS (
|
||||
-- On récupère les 60 derniers jours de données
|
||||
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 (
|
||||
-- On génère une série de 60 minutes jusqu'à maintenant
|
||||
SELECT generate_series(
|
||||
date_trunc('minute', now()) - interval '59 minutes',
|
||||
date_trunc('minute', now()),
|
||||
interval '1 minute'
|
||||
) as slot
|
||||
),
|
||||
filled_minute_data AS (
|
||||
-- On crée une ligne pour chaque minute et chaque service
|
||||
SELECT
|
||||
s.id as service_id,
|
||||
ts.slot as timestamp,
|
||||
-- On prend la valeur la plus récente si plusieurs existent dans la même minute,
|
||||
-- sinon 3 s'il n'y a rien (COALESCE)
|
||||
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 (
|
||||
-- 60 dernières minutes
|
||||
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', -- 23 car on inclut l'heure actuelle pour faire 24h
|
||||
date_trunc('hour', now()),
|
||||
interval '1 hour'
|
||||
) as slot
|
||||
),
|
||||
filled_hours_data AS (
|
||||
SELECT
|
||||
s.id as service_id,
|
||||
ts.slot as timestamp,
|
||||
-- On récupère tous les statuts bruts de base_data qui tombent dans cette heure
|
||||
-- On garde la liste pour calculer le ratio après
|
||||
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 -- Aucune donnée (Inconnu)
|
||||
WHEN ratio >= 0.95 THEN 1 -- Presque tout l'heure est OK
|
||||
WHEN ratio >= 0.5 THEN 2 -- Moitié de l'heure instable
|
||||
ELSE 0 -- Majorité de l'heure en panne
|
||||
END
|
||||
) ORDER BY timestamp DESC
|
||||
) as data
|
||||
FROM filled_hours_data
|
||||
GROUP BY service_id
|
||||
),
|
||||
time_slots_days AS (
|
||||
-- On génère les 60 derniers jours
|
||||
SELECT generate_series(
|
||||
date_trunc('day', now()) - interval '59 days',
|
||||
date_trunc('day', now()),
|
||||
interval '1 day'
|
||||
) as slot
|
||||
),
|
||||
filled_days_data AS (
|
||||
-- On calcule le ratio pour chaque jour et chaque service
|
||||
SELECT
|
||||
s.id as service_id,
|
||||
ts.slot as timestamp,
|
||||
-- Ratio d'uptime : (points OK) / (points totaux réels)
|
||||
-- Si aucun point n'existe du tout pour le jour, on met 3 (Inconnu)
|
||||
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 -- Aucune donnée
|
||||
WHEN ratio >= 0.98 THEN 1 -- Seuil d'excellence journalier
|
||||
WHEN ratio >= 0.5 THEN 2 -- Journée instable
|
||||
ELSE 0 -- Service majoritairement HS ce jour-là
|
||||
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, -- La virgule ici est cruciale
|
||||
'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;
|
||||
Reference in New Issue
Block a user