diff --git a/README.md b/README.md index 0485261..77610e8 100644 --- a/README.md +++ b/README.md @@ -75,4 +75,17 @@ WITH yac AS ( ) SELECT * from yac -where years_at_company < 0 or years_at_company > 60; \ No newline at end of file +where years_at_company < 0 or years_at_company > 60; + + +-- Performance review: number of steps loaded +select c.name, s.name, count(*) +from performance_review_step s +inner join performance_review r on r.id = s.review_id +inner join performance_cycle c on c.id = r.cycle_id +group by c.name, s.name, s.sequence_number +order by c.name, s.sequence_number; + +-- Steps not linked to a review +select count(*) from performance_review_step +where review_id is null; \ No newline at end of file diff --git a/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql b/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql index 9a8d31f..12ed66c 100644 --- a/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql +++ b/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql @@ -31,8 +31,55 @@ steps as ( step_submission_date::date as completed_at from {{ source('tap_spreadsheets_anywhere', 'performance_review_steps') }} where is_not_removed_from_task = 1 +), + +mandatory_steps as ( + select 'Employee Self Review' as name, 1 as sequence_number + union all select 'Manager Review', 2 + union all select 'Performance Conversation & Manager Sign-off', 3 + union all select 'Employee Sign-Off', 4 +), + +-- Get all reviews that match our criteria +filtered_reviews as ( + select distinct + r.review_id, + r.user_id, + r.task_name + from review_base r + where r.task_name like 'Performance Review 2024%' +), + +-- Generate all expected steps for these reviews +expected_steps as ( + select + r.review_id, + r.user_id, + r.task_name, + m.name, + m.sequence_number + from filtered_reviews r + cross join mandatory_steps m +), + +-- Find which expected steps are missing from the source data +missing_steps as ( + select + e.user_id, + e.task_name, + e.name, + e.sequence_number, + 'Not started' as status, + null::date as completed_at + from expected_steps e + left join steps s + on e.user_id = s.user_id + and e.task_name like s.task_name || '%' -- Also map for remapped cycle generic/n-1 + and e.name = s.name + where s.user_id is null ) +-- Combine existing steps with missing steps select row_number() over (order by s.user_id, s.task_name, s.name)::bigint as id, r.review_id, @@ -41,7 +88,11 @@ select s.status, s.completed_at, null::date as due -from steps s +from ( + select * from steps + union all + select * from missing_steps +) s left join review_base r on r.user_id = s.user_id and r.task_name like s.task_name || '%' -- Also map for remapped cycle generic/n-1 \ No newline at end of file