Files
lakehouse-sarens-integration/transform/models/tap_spreadsheets_anywhere/performance_review.sql

81 lines
2.8 KiB
SQL

{{ config(materialized='table') }}
with step_agg as (
select
user_id::text as user_id,
task_name,
max(step_submission_date::date) filter (where task_status = 'Completed') as completed_at,
max(task_status) as status
from {{ source('tap_spreadsheets_anywhere', 'performance_review_steps') }}
where is_not_removed_from_task = 1
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,
task_name,
max(final_rating) as overall_rating
from {{ source('tap_spreadsheets_anywhere', 'performance_review_total_scoring') }}
group by 1,2
),
worker_map as (
select id as worker_id, worker_hris_id::text
from {{ ref('worker') }}
),
cycle_map as (
select id as cycle_id, name
from {{ ref('performance_cycle') }}
),
combined as (
select
s.user_id,
s.task_name,
s.status,
s.completed_at,
ts.overall_rating,
w.worker_id,
c.cycle_id
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
)
select
row_number() over (order by user_id, task_name)::bigint as id,
null::date as start,
status,
nullif(regexp_replace(overall_rating, '^(\d+).*', '\1'), '')::numeric as overall_rating_value,
overall_rating as overall_rating_text,
cycle_id,
worker_id,
null::bigint as reviewer_id,
completed_at as completed,
null::date as due
from combined