|
1 | 1 | -- CI workflow health
|
2 |
| -WITH |
3 |
| - -- bar() function renders colored output, and uses one character rendering (boxes), so has less precision within same width |
4 |
| - FUNCTION ascii_bar(value double) |
5 |
| - RETURNS varchar |
6 |
| - DETERMINISTIC |
7 |
| - BEGIN |
8 |
| - DECLARE max_width double DEFAULT 20; |
9 |
| - DECLARE clamped_value double; |
10 |
| - SET clamped_value = greatest(0, least(1, value)); |
11 |
| - RETURN array_join( |
12 |
| - repeat('█', |
13 |
| - greatest(0, CAST(floor(max_width * clamped_value) AS integer) - 1)), '') |
14 |
| - || ARRAY[' ', '▏', '▎', '▍', '▌', '▋', '▊', '▉', '█'][cast((clamped_value % (1e0 / max_width)) * max_width * 8 + 1 as int)]; |
15 |
| - END |
| 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 |
16 | 12 | WITH
|
17 | 13 | runs AS (
|
18 | 14 | SELECT
|
19 |
| - CASE head_branch |
20 |
| - WHEN 'master' THEN head_branch |
21 |
| - ELSE '[other]' |
22 |
| - END AS branch |
23 |
| - , created_at |
| 15 | + date(created_at) AS created_at |
24 | 16 | , conclusion
|
| 17 | + , count(*) AS num_runs |
| 18 | + , count(*) FILTER (WHERE conclusion = 'success') AS num_success |
25 | 19 | FROM runs
|
26 |
| - WHERE owner = 'trinodb' AND repo = 'trino' |
27 |
| - AND name = 'ci' AND created_at >= CURRENT_DATE - INTERVAL '30' DAY |
| 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 |
28 | 39 | )
|
29 |
| -, intervals(days, label) AS ( |
30 |
| - VALUES |
31 |
| - (INTERVAL '1' DAY, '1 day') |
32 |
| - , (INTERVAL '3' DAY, '3 days') |
33 |
| - , (INTERVAL '7' DAY, '7 days') |
34 |
| - , (INTERVAL '30' DAY, '30 days') |
| 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 |
35 | 56 | )
|
36 | 57 | SELECT
|
37 |
| - branch AS "Branch" |
38 |
| - , intervals.label AS "Interval" |
39 |
| - , ascii_bar(1e0 * count(1) FILTER (WHERE conclusion = 'success') / count(1)) AS "Success ratio chart" |
40 |
| - , round(100e0 * count(1) FILTER (WHERE conclusion = 'success') / count(1), 1) AS "Success percent" |
41 |
| - , count(1) FILTER (WHERE created_at > now() - intervals.days) AS "Number of runs" |
42 |
| -FROM intervals |
43 |
| -JOIN runs ON runs.created_at > now() - intervals.days |
44 |
| -GROUP BY branch, intervals.days, intervals.label |
45 |
| -ORDER BY branch DESC, intervals.days |
| 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 |
46 | 63 | ;
|
0 commit comments