1
+ DROP VIEW IF EXISTS EVALUATION_VIEW;
2
+ CREATE VIEW EVALUATION_VIEW AS
3
+ WITH team_quarters AS (
4
+ SELECT
5
+ t .id AS team_id,
6
+ t .name AS team_name,
7
+ q .id AS quarter_id,
8
+ q .label AS quarter_label
9
+ FROM team t
10
+ CROSS JOIN quarter q
11
+ ),
12
+ objectives AS (
13
+ SELECT
14
+ o .team_id ,
15
+ o .quarter_id ,
16
+ COUNT (DISTINCT o .id ) AS objective_amount,
17
+ COUNT (* ) FILTER (WHERE o .state IN (' SUCCESSFUL' , ' NOTSUCCESSFUL' )) AS completed_objectives_amount,
18
+ COUNT (* ) FILTER (WHERE o .state = ' SUCCESSFUL' ) AS successfully_completed_objectives_amount
19
+ FROM OBJECTIVE o
20
+ GROUP BY o .team_id , o .quarter_id
21
+ ),
22
+ latest_check_ins AS (
23
+ SELECT DISTINCT ON (ci .key_result_id )
24
+ ci .key_result_id ,
25
+ ci .value_metric ,
26
+ ci .zone ,
27
+ kr .key_result_type ,
28
+ kr .stretch_goal ,
29
+ kr .baseline ,
30
+ sub_o .team_id ,
31
+ sub_o .quarter_id
32
+ FROM check_in ci
33
+ RIght JOIN key_result kr ON ci .key_result_id = kr .id
34
+ INNER JOIN objective sub_o ON kr .objective_id = sub_o .id
35
+ ORDER BY ci .key_result_id , ci .modified_on DESC
36
+ ),
37
+ key_result_counts AS (
38
+ SELECT
39
+ team_id,
40
+ quarter_id,
41
+ COUNT (* ) FILTER (WHERE key_result_type = ' ordinal' ) AS amount_key_results_ordinal,
42
+ COUNT (* ) FILTER (WHERE key_result_type = ' metric' ) AS amount_key_results_metric,
43
+ COUNT (* ) FILTER (
44
+ WHERE (key_result_type = ' ordinal' AND zone IN (' TARGET' , ' STRETCH' ))
45
+ OR (key_result_type = ' metric' AND (value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )>= 0 .7 )
46
+ ) AS amount_key_results_in_target_or_stretch,
47
+ COUNT (* ) FILTER (
48
+ WHERE (key_result_type = ' ordinal' AND zone = ' FAIL' )
49
+ OR (key_result_type = ' metric' AND (value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 ) < 0 .3 )
50
+ ) AS amount_key_results_in_fail,
51
+ COUNT (* ) FILTER (
52
+ WHERE (key_result_type = ' ordinal' AND zone = ' COMMIT' )
53
+ OR (key_result_type = ' metric' AND (value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 ) BETWEEN 0 .3 AND 0 .7 )
54
+ ) AS amount_key_results_in_commit,
55
+ COUNT (* ) FILTER (
56
+ WHERE (key_result_type = ' ordinal' AND zone = ' TARGET' )
57
+ OR (key_result_type = ' metric' AND (value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 ) BETWEEN 0 .7 AND 1 )
58
+ ) AS amount_key_results_in_target,
59
+ COUNT (* ) FILTER (
60
+ WHERE (key_result_type = ' ordinal' AND zone = ' STRETCH' )
61
+ OR (key_result_type = ' metric' AND ((value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )) >= 1 )
62
+ ) AS amount_key_results_in_stretch
63
+ FROM latest_check_ins
64
+ GROUP BY team_id, quarter_id
65
+ )
66
+ SELECT
67
+ tq .team_id ,
68
+ tq .team_name ,
69
+ tq .quarter_id ,
70
+ tq .quarter_label ,
71
+ COALESCE(o .objective_amount , 0 ) AS objective_amount,
72
+ COALESCE(o .completed_objectives_amount , 0 ) AS completed_objectives_amount,
73
+ COALESCE(o .successfully_completed_objectives_amount , 0 ) AS successfully_completed_objectives_amount,
74
+ COALESCE(kr .amount_key_results_ordinal , 0 ) AS amount_key_results_ordinal,
75
+ COALESCE(kr .amount_key_results_metric , 0 ) AS amount_key_results_metric,
76
+ COALESCE(kr .amount_key_results_in_target_or_stretch , 0 ) AS amount_key_results_in_target_or_stretch,
77
+ COALESCE(kr .amount_key_results_in_fail , 0 ) AS amount_key_results_in_fail,
78
+ COALESCE(kr .amount_key_results_in_commit , 0 ) AS amount_key_results_in_commit,
79
+ COALESCE(kr .amount_key_results_in_target , 0 ) AS amount_key_results_in_target,
80
+ COALESCE(kr .amount_key_results_in_stretch , 0 ) AS amount_key_results_in_stretch
81
+ FROM team_quarters tq
82
+ LEFT JOIN objectives o
83
+ ON tq .team_id = o .team_id
84
+ AND tq .quarter_id = o .quarter_id
85
+ LEFT JOIN key_result_counts kr
86
+ ON tq .team_id = kr .team_id
87
+ AND tq .quarter_id = kr .quarter_id
88
+ order by tq .team_id , tq .quarter_id ;
0 commit comments