From 461a7eb9aa7de50c295c4db21b39906890b2fbcd Mon Sep 17 00:00:00 2001 From: Jeroen Date: Tue, 12 Aug 2025 13:04:44 +0200 Subject: [PATCH] Split out Performance Review 2024 into Generic and n-1 managers --- .../performance_cycle.sql | 49 ++++++++++++++++--- .../performance_review.sql | 24 ++++++++- .../performance_review_step.sql | 8 +-- 3 files changed, 68 insertions(+), 13 deletions(-) diff --git a/transform/models/tap_spreadsheets_anywhere/performance_cycle.sql b/transform/models/tap_spreadsheets_anywhere/performance_cycle.sql index 2b43289..54a37e3 100644 --- a/transform/models/tap_spreadsheets_anywhere/performance_cycle.sql +++ b/transform/models/tap_spreadsheets_anywhere/performance_cycle.sql @@ -17,13 +17,46 @@ with distinct_cycles as ( from {{ source('tap_spreadsheets_anywhere', 'performance_review_steps') }} --where is_not_removed_from_task = 1 group by task_name +), + +base_records as ( + select + dense_rank() over (order by task_name)::bigint as id, + cycle_start_date::date as start_date, + cycle_end_date::date as end_date, + task_name as name, + 'Closed' as status, -- overwritten logic for Sarens + 'annual' as type + from distinct_cycles +), + +-- Generate additional records for Performance Review 2024 +additional_records as ( + select + (select max(id) from base_records) + 1 as id, + start_date, + end_date, + 'Performance Review 2024 - Generic' as name, + status, + type + from base_records + where name = 'Performance Review 2024' + + union all + + select + (select max(id) from base_records) + 2 as id, + start_date, + end_date, + 'Performance Review 2024 - n-1 managers' as name, + status, + type + from base_records + where name = 'Performance Review 2024' ) -select - dense_rank() over (order by task_name)::bigint as id, - cycle_start_date::date as start_date, - cycle_end_date::date as end_date, - task_name as name, - 'Closed' as status, -- overwritten logic for Sarens - 'annual' as type -from distinct_cycles +-- Combine original records with additional records +select * from base_records +where name != 'Performance Review 2024' +union all +select * from additional_records \ No newline at end of file diff --git a/transform/models/tap_spreadsheets_anywhere/performance_review.sql b/transform/models/tap_spreadsheets_anywhere/performance_review.sql index 9896210..9d723d7 100644 --- a/transform/models/tap_spreadsheets_anywhere/performance_review.sql +++ b/transform/models/tap_spreadsheets_anywhere/performance_review.sql @@ -11,6 +11,28 @@ with step_agg as ( group by 1,2 ), +-- When task_name = "Performance Review 2024", we need to update it to either "Performance Review 2024 - Generic" or "Performance Review 2024 - n-1 managers" +-- This is determined based on whether for the user_id, there exists a step which is not in ('Employee Self Review', 'Manager Review', 'Performance Conversation & Manager Sign-off', or 'Employee Sign-off') +remapped_steps as ( + select + user_id, + case + when task_name != 'Performance Review 2024' + then task_name + when exists ( + select 1 + from {{ source('tap_spreadsheets_anywhere', 'performance_review_steps') }} s + where s.user_id = step_agg.user_id + and s.task_name = 'Performance Review 2024' + and s.step_title not in ('Employee Self Review', 'Manager Review', 'Performance Conversation & Manager Sign-off', 'Employee Sign-Off') + ) then 'Performance Review 2024 - n-1 managers' + else 'Performance Review 2024 - Generic' + end as task_name, + completed_at, + status + from step_agg +), + total_scoring as ( select user_id::text as user_id, @@ -39,7 +61,7 @@ combined as ( ts.overall_rating, w.worker_id, c.cycle_id - from step_agg s + from remapped_steps s left join total_scoring ts using (user_id, task_name) left join worker_map w on w.worker_hris_id = s.user_id left join cycle_map c on c.name = s.task_name diff --git a/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql b/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql index 8b329d4..9a8d31f 100644 --- a/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql +++ b/transform/models/tap_spreadsheets_anywhere/performance_review_step.sql @@ -19,10 +19,10 @@ steps as ( step_title as name, case when step_title in ('Auto-évaluation des employés', 'Employee Self Review', 'Sarens Projects Review', - 'Approbation des employés', 'Strategy Review', 'Finance Review', - 'Sales Review', 'Fleet Review', 'Self Review', 'LCM Review', 'Operations Review') then 1 + 'Approbation des employés', + 'Self Review') then 1 when step_title in ('Évaluation du manager', 'Functional Manager Review', 'Discussion et approbation du manager', - 'Manager Review') then 2 + 'Manager Review', 'Strategy Review', 'Finance Review', 'Sales Review', 'Fleet Review', 'LCM Review', 'Operations Review') then 2 when step_title in ('HR Review', 'SHEQ Review', 'Performance Conversation & Manager Sign-off') then 3 when step_title = 'Employee Sign-Off' then 4 else null -- fallback for any unexpected values @@ -44,4 +44,4 @@ select from steps s left join review_base r on r.user_id = s.user_id - and r.task_name = s.task_name \ No newline at end of file + and r.task_name like s.task_name || '%' -- Also map for remapped cycle generic/n-1 \ No newline at end of file