@@ -19,65 +19,69 @@ WITH team_quarters AS (
19
19
FROM OBJECTIVE o
20
20
GROUP BY o .team_id , o .quarter_id
21
21
),
22
- latest_check_ins AS (
23
- SELECT DISTINCT ON (ci . key_result_id )
24
- ci . key_result_id ,
22
+ kr_latest_check_in AS (
23
+ SELECT DISTINCT ON (kr . id )
24
+ kr . id as key_result_id,
25
25
ci .value_metric ,
26
26
ci .zone ,
27
27
kr .key_result_type ,
28
28
kr .stretch_goal ,
29
29
kr .baseline ,
30
30
sub_o .team_id ,
31
31
sub_o .quarter_id
32
- FROM check_in ci
33
- RIght JOIN key_result kr ON ci .key_result_id = kr .id
32
+ FROM key_result kr
33
+ LEFT JOIN CHECK_IN ci ON KR .ID = ci .KEY_RESULT_ID AND ci .MODIFIED_ON = (SELECT MAX (CC .MODIFIED_ON )
34
+ FROM CHECK_IN CC
35
+ WHERE CC .KEY_RESULT_ID = ci .KEY_RESULT_ID )
34
36
INNER JOIN objective sub_o ON kr .objective_id = sub_o .id
35
- ORDER BY ci . key_result_id , ci .modified_on DESC
37
+ ORDER BY kr . id , ci .modified_on DESC
36
38
),
37
39
key_result_counts AS (
38
40
SELECT
39
41
team_id,
40
42
quarter_id,
43
+ COUNT (* ) AS amount_key_results,
41
44
COUNT (* ) FILTER (WHERE key_result_type = ' ordinal' ) AS amount_key_results_ordinal,
42
45
COUNT (* ) FILTER (WHERE key_result_type = ' metric' ) AS amount_key_results_metric,
43
46
COUNT (* ) FILTER (
44
47
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 )
48
+ OR (key_result_type = ' metric' AND COALESCE((( value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )), 0 )>= 0 .7 )
46
49
) AS amount_key_results_in_target_or_stretch,
47
50
COUNT (* ) FILTER (
48
51
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 )
52
+ OR (key_result_type = ' metric' AND COALESCE((( value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )), 0 ) < 0 .3 )
50
53
) AS amount_key_results_in_fail,
51
54
COUNT (* ) FILTER (
52
55
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 )
56
+ OR (key_result_type = ' metric' AND COALESCE((( value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )), 0 ) BETWEEN 0 .3 AND 0 .7 )
54
57
) AS amount_key_results_in_commit,
55
58
COUNT (* ) FILTER (
56
59
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 )
60
+ OR (key_result_type = ' metric' AND COALESCE((( value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )), 0 ) BETWEEN 0 .7 AND 1 )
58
61
) AS amount_key_results_in_target,
59
62
COUNT (* ) FILTER (
60
63
WHERE (key_result_type = ' ordinal' AND zone = ' STRETCH' )
61
- OR (key_result_type = ' metric' AND (( value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )) >= 1 )
64
+ OR (key_result_type = ' metric' AND COALESCE((( value_metric - baseline) / NULLIF(stretch_goal - baseline, 0 )), 0 ) >= 1 )
62
65
) AS amount_key_results_in_stretch
63
- FROM latest_check_ins
66
+ FROM kr_latest_check_in
64
67
GROUP BY team_id, quarter_id
65
68
)
66
69
SELECT
67
70
tq .team_id ,
68
71
tq .team_name ,
69
72
tq .quarter_id ,
70
73
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
74
+ o .objective_amount ,
75
+ o .completed_objectives_amount ,
76
+ o .successfully_completed_objectives_amount ,
77
+ kr .amount_key_results ,
78
+ kr .amount_key_results_ordinal ,
79
+ kr .amount_key_results_metric ,
80
+ kr .amount_key_results_in_target_or_stretch ,
81
+ kr .amount_key_results_in_fail ,
82
+ kr .amount_key_results_in_commit ,
83
+ kr .amount_key_results_in_target ,
84
+ kr .amount_key_results_in_stretch
81
85
FROM team_quarters tq
82
86
LEFT JOIN objectives o
83
87
ON tq .team_id = o .team_id
0 commit comments