Compare commits
3 Commits
735250c4c7
...
eaaf51f699
| Author | SHA1 | Date | |
|---|---|---|---|
| eaaf51f699 | |||
| 461a7eb9aa | |||
| 9a7059dcdf |
63
README.md
63
README.md
@@ -26,3 +26,66 @@ DROP TABLE raw.performance_review_sub_scoring;
|
||||
DROP TABLE raw.performance_review_total_scoring;
|
||||
DROP TABLE raw.positions;
|
||||
DROP TABLE raw.workers;
|
||||
|
||||
|
||||
|
||||
Data quality checks:
|
||||
|
||||
-- Total worker count
|
||||
SELECT count(*)
|
||||
from clean.worker;
|
||||
|
||||
-- Active workers
|
||||
SELECT count(*)
|
||||
from clean.worker
|
||||
where employment_exit_date is null;
|
||||
|
||||
-- Number of job change / position change records
|
||||
WITH history_counts AS (
|
||||
SELECT w.id, count(*) as history_count
|
||||
from clean.worker w
|
||||
left join clean.job_change jc on w.id = jc.worker_id
|
||||
group by w.id
|
||||
)
|
||||
SELECT history_count, count(*)
|
||||
from history_counts
|
||||
group by history_count
|
||||
order by history_count;
|
||||
|
||||
-- Years at the company
|
||||
WITH yac AS (
|
||||
SELECT
|
||||
w.id,
|
||||
EXTRACT('YEAR' FROM AGE(COALESCE(employment_exit_date, CURRENT_DATE), employment_start)) AS years_at_company
|
||||
FROM clean.worker w
|
||||
)
|
||||
SELECT
|
||||
yac.years_at_company,
|
||||
COUNT(*)
|
||||
FROM yac
|
||||
GROUP BY yac.years_at_company
|
||||
ORDER BY yac.years_at_company
|
||||
|
||||
-- Worker id's with < 0 years at company or > 60 years
|
||||
WITH yac AS (
|
||||
SELECT
|
||||
w.id, w.worker_hris_id, w.employment_start, w.employment_exit_date,
|
||||
EXTRACT('YEAR' FROM AGE(COALESCE(employment_exit_date, CURRENT_DATE), employment_start)) AS years_at_company
|
||||
FROM clean.worker w
|
||||
)
|
||||
SELECT *
|
||||
from yac
|
||||
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;
|
||||
@@ -13,6 +13,7 @@ latest_departments as (
|
||||
from {{ source('tap_spreadsheets_anywhere', 'departments') }}
|
||||
) t
|
||||
where rn = 1
|
||||
and id not in ('CAD', 'CSAD')
|
||||
),
|
||||
department_tree as (
|
||||
-- Anchor: top-level department (parent_id is set to Sarens Group in the Excel)
|
||||
|
||||
@@ -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
|
||||
@@ -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
|
||||
|
||||
@@ -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
|
||||
@@ -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 = s.task_name
|
||||
and r.task_name like s.task_name || '%' -- Also map for remapped cycle generic/n-1
|
||||
Reference in New Issue
Block a user