|
1 | 1 | -- CI workflow health |
| 2 | +-- Percentage of successful runs of the `ci` workflow on the master branch. |
| 3 | +WITH FUNCTION vertical_bar(value DOUBLE, day DATE) |
| 4 | + RETURNS VARCHAR |
| 5 | + DETERMINISTIC |
| 6 | + RETURN CASE |
| 7 | + -- for weekends, if missing or zero, grey it out |
| 8 | + WHEN value = 0 AND day_of_week(day) IN (6,7) THEN '░' |
| 9 | + -- map [0.0, 1.0] to [1, 9] |
| 10 | + ELSE ARRAY[' ', '▁', '▂', '▃', '▄', '▅', '▆', '▇', '█'][cast(value * 8 + 1 as int)] |
| 11 | +END |
| 12 | +WITH |
| 13 | +runs AS ( |
| 14 | + SELECT |
| 15 | + date(created_at) AS created_at |
| 16 | + , conclusion |
| 17 | + , count(*) AS num_runs |
| 18 | + , count(*) FILTER (WHERE conclusion = 'success') AS num_success |
| 19 | + FROM runs |
| 20 | + WHERE owner = 'trinodb' AND repo = 'trino' AND name = 'ci' |
| 21 | + AND head_branch = 'master' AND event != 'pull_request' AND status = 'completed' |
| 22 | + AND created_at >= CURRENT_DATE - INTERVAL '7' DAY |
| 23 | + GROUP BY date(created_at), conclusion |
| 24 | +) |
| 25 | +, days AS ( |
| 26 | + SELECT seq.day |
| 27 | + FROM (SELECT min(created_at) AS first_day , max(created_at) AS last_day FROM runs) range |
| 28 | + CROSS JOIN UNNEST (sequence(range.first_day, range.last_day)) seq(day) |
| 29 | +) |
| 30 | +, daily AS ( |
| 31 | + SELECT |
| 32 | + created_at |
| 33 | + , conclusion |
| 34 | + , num_runs |
| 35 | + , num_success |
| 36 | + , 1e0 * num_success / num_runs AS ratio |
| 37 | + FROM days |
| 38 | + LEFT JOIN runs ON runs.created_at = days.day |
| 39 | +) |
| 40 | +, summary AS ( |
| 41 | + SELECT |
| 42 | + sum(num_runs) AS num_runs |
| 43 | + , sum(num_success) AS num_success |
| 44 | + , 1e0 * sum(num_success) / sum(num_runs) AS ratio |
| 45 | + , array_join(array_agg(vertical_bar(coalesce(ratio, 0), created_at) ORDER BY created_at DESC), '') AS chart |
| 46 | + FROM daily |
| 47 | +) |
| 48 | +, latest AS ( |
| 49 | + SELECT |
| 50 | + num_runs |
| 51 | + , num_success |
| 52 | + , 1e0 * num_success / num_runs AS ratio |
| 53 | + FROM runs |
| 54 | + ORDER BY created_at DESC |
| 55 | + LIMIT 1 |
| 56 | +) |
2 | 57 | SELECT |
3 | | - CASE head_branch |
4 | | - WHEN 'master' THEN head_branch |
5 | | - ELSE '[other]' |
6 | | - END AS branch |
7 | | - , count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '1' DAY) AS today_count |
8 | | - , round(count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '1' DAY AND conclusion = 'success') / CAST(count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '1' DAY) AS double), 2) AS today_success |
9 | | - , count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '3' DAY) AS "3day_count" |
10 | | - , round(count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '3' DAY AND conclusion = 'success') / CAST(count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '3' DAY) AS double), 2) AS "3day_success" |
11 | | - , count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '7' DAY) AS week_count |
12 | | - , round(count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '7' DAY AND conclusion = 'success') / CAST(count(1) FILTER (WHERE created_at > CURRENT_DATE - INTERVAL '7' DAY) AS double), 2) AS week_success |
13 | | - , count(1) AS month_count |
14 | | - , round(count(1) FILTER (WHERE conclusion = 'success') / CAST(count(1) AS double), 2) AS month_success |
15 | | -FROM runs |
16 | | -WHERE owner = 'trinodb' AND repo = 'trino' |
17 | | -AND name = 'ci' AND created_at >= CURRENT_DATE - INTERVAL '30' DAY |
18 | | -GROUP BY 1 |
19 | | -ORDER BY 1 |
| 58 | + format('%.1f%% (%d/%d)', 100e0 * latest.ratio, latest.num_success, latest.num_runs) AS "Today" |
| 59 | + , format('%.1f%% (%d/%d)', 100e0 * summary.ratio, summary.num_success, summary.num_runs) AS "Weekly" |
| 60 | + , summary.chart AS "Daily (desc)" |
| 61 | +FROM summary |
| 62 | +CROSS JOIN latest |
20 | 63 | ; |
0 commit comments