Files
lakehouse-sarens-integration/transform/models/tap_spreadsheets_anywhere/job_change.sql
Jeroen aa19a53d51 Minor fixes after workshop
Worker: Also consider non-primary positions for the department
identification
Worker: Don't load users with non-numeric IDs
Job change: Select position with primary = Yes, if it exists
2025-07-18 11:35:15 +02:00

134 lines
6.3 KiB
SQL

{{
config(
materialized='table'
)
}}
WITH latest_workers AS (
SELECT DISTINCT ON (user_id) *
FROM {{ source('tap_spreadsheets_anywhere', 'workers') }}
WHERE _sdc_deleted_at IS NULL
ORDER BY user_id, _sdc_received_at DESC
),
latest_departments AS (
SELECT *
FROM {{ ref('department') }}
),
-- note: Positions ID is not unique, hence removed the full deduplication logic
-- however, we had positions with same start date while both having primary position set to true, hence only selecting a random one for now (temp workaround)
deduplicated_positions AS (
SELECT DISTINCT ON (assigned_employee_id, assigned_employee_effective_date)
*
FROM {{ source('tap_spreadsheets_anywhere', 'positions') }}
WHERE _sdc_deleted_at IS NULL
ORDER BY assigned_employee_id,
assigned_employee_effective_date,
CASE WHEN primary_position = 'Yes' THEN 1 ELSE 0 END DESC,
_sdc_received_at DESC
),
transformed_worker AS (
SELECT worker_hris_id, id
FROM {{ ref('worker') }}
),
position_details AS (
SELECT
p.*,
w.user_id as worker_hris_id,
w.collar_type AS new_collar_type,
w.user_contract_type AS new_contract_type,
w.contracting_company AS new_contracting_company,
d.path::ltree AS new_department_path,
d.manager_id::BIGINT AS new_manager_id,
COALESCE(p.assigned_employee_effective_date, w.original_hire_date)::DATE AS new_job_effective_date, -- Use original hire date if position effective date is not available (this is the case when there is no position record)
COALESCE(p.fte_utilized_by_employee_in_this_position * 100, 100) AS new_fte_percentage, -- Default to 100% if not specified
tw.id as worker_id
FROM transformed_worker tw
LEFT JOIN deduplicated_positions p
ON p.assigned_employee_id = tw.worker_hris_id
LEFT JOIN latest_departments d
ON p.assigned_unit_id = d.department_hris_id
LEFT JOIN latest_workers w ON tw.worker_hris_id = w.user_id
),
job_changes_with_history AS (
SELECT
*,
LAG(position_title) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_function_title,
LAG(NULL::INTEGER) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_function_level, -- Not available
LAG(w.user_type) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_type,
LAG(new_fte_percentage) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_fte_percentage,
LAG(w.location) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_work_location,
LAG(NULL::VARCHAR) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_work_location_type,
LAG(p.assigned_unit) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_team,
LAG(w.depot_cost_center) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_cost_center,
LAG(NULL::INTEGER) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_salary_monthly_gross_fixed,
LAG(NULL::INTEGER) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_salary_yearly_gross_fixed,
LAG(NULL::INTEGER) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_salary_yearly_gross_variable,
LAG(NULL::INTEGER) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_salary_yearly_fully_loaded_cost,
LAG(NULL::VARCHAR(3)) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_salary_currency,
LAG(NULL::INTEGER) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_salary_hay_grade,
LAG(d.path::ltree) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_department_path,
LAG(d.manager_id::BIGINT) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_manager_id,
LAG(w.collar_type) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_collar_type,
LAG(w.user_contract_type) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_contract_type,
LAG(w.contracting_company) OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) AS previous_contracting_company,
ROW_NUMBER() OVER (PARTITION BY worker_id ORDER BY new_job_effective_date DESC) = 1 AS latest,
ROW_NUMBER() OVER (PARTITION BY worker_id ORDER BY new_job_effective_date) = 1 AS is_first
FROM position_details p
LEFT JOIN latest_workers w ON p.assigned_employee_id = w.user_id
LEFT JOIN latest_departments d ON p.assigned_unit_id = d.department_hris_id
)
SELECT
ROW_NUMBER() OVER () AS id,
NULL::VARCHAR AS first_name,
NULL::VARCHAR AS last_name,
position_title AS new_function_title,
NULL::INTEGER AS new_function_level, -- Not available
user_type AS new_type,
ROUND(new_fte_percentage)::INTEGER AS new_fte_percentage,
location AS new_work_location,
NULL::VARCHAR AS new_work_location_type,
assigned_unit AS new_team,
depot_cost_center AS new_cost_center,
NULL::INTEGER AS new_salary_monthly_gross_fixed,
NULL::INTEGER AS new_salary_yearly_gross_fixed,
NULL::INTEGER AS new_salary_yearly_gross_variable,
NULL::INTEGER AS new_salary_yearly_fully_loaded_cost,
NULL::VARCHAR(3) AS new_salary_currency,
NULL::INTEGER AS new_salary_hay_grade,
previous_function_title,
previous_function_level,
previous_type,
previous_fte_percentage,
previous_work_location,
previous_work_location_type,
previous_team,
previous_cost_center,
previous_salary_monthly_gross_fixed,
previous_salary_yearly_gross_fixed,
previous_salary_yearly_gross_variable,
previous_salary_yearly_fully_loaded_cost,
previous_salary_currency,
previous_salary_hay_grade,
COALESCE(NULL, false) AS promotion, -- Optionally update later
latest,
new_job_effective_date,
new_department_path,
new_manager_id,
previous_department_path,
previous_manager_id,
worker_id,
is_first AS new_hire,
new_collar_type,
new_contract_type,
new_contracting_company,
previous_collar_type,
previous_contract_type,
previous_contracting_company
FROM job_changes_with_history