Files
lakehouse-sarens-integration/transform/models/tap_spreadsheets_anywhere/worker.sql
2025-06-17 17:06:57 +02:00

129 lines
4.3 KiB
SQL

{{
config(
materialized='table'
)
}}
-- Filter "users" based on latest ELT load
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
),
-- Filter "positions" based on latest ELT load
-- + only primary positions (need additional view for multi-positions)
-- + only for latest position of a user
latest_positions AS (
SELECT DISTINCT ON (assigned_employee_id) *
FROM {{ source('tap_spreadsheets_anywhere', 'positions') }}
WHERE _sdc_deleted_at IS NULL
AND primary_position = 'Yes'
ORDER BY assigned_employee_id, _sdc_received_at DESC, assigned_employee_effective_date
),
joined_data AS (
SELECT
w.user_id,
w.birth_date::DATE AS date_of_birth,
w.gender,
w.nationality,
NULL::VARCHAR AS first_name, -- Not available
NULL::VARCHAR AS last_name, -- Not available
NULL::VARCHAR AS ethnicity,
NULL::VARCHAR AS degree_level,
NULL::VARCHAR AS degree_name,
NULL::VARCHAR AS address_line_1,
NULL::VARCHAR AS address_line_2,
NULL::VARCHAR AS address_zip,
NULL::VARCHAR AS address_city,
NULL::VARCHAR AS address_country,
NULL::VARCHAR AS phone_number,
NULL::VARCHAR AS driver_license,
w.original_hire_date::DATE AS employment_start,
w.user_type AS employment_type,
w.user_contract_type AS employment_contract_type,
w.contracting_company AS employment_contracting_company,
w.collar_type AS employment_collar_type,
NULL::INTEGER AS employment_function_level,
p.position_title AS employment_function_title,
p.assigned_unit AS employment_team,
NULL::INTEGER AS employment_notice_period,
depot_cost_center AS employment_cost_center,
w.termination_type AS employment_exit_type,
w.termination_date::DATE AS employment_exit_date,
w.termination_reason AS employment_exit_reason,
NULL::INTEGER AS performance_rating,
NULL::DATE AS performance_date,
d.manager_id::BIGINT AS employment_manager_id,
NULL::INTEGER AS employment_criticality,
NULL::VARCHAR AS employment_probation_status,
NULL::DATE AS employment_probation_end_date,
d.path::ltree AS employment_department_path,
NULL::VARCHAR(254) AS email,
NULL::DATE AS employment_earliest_retirement_date,
ROUND(p.fte_utilized_by_employee_in_this_position * 100)::INTEGER AS employment_fte_percentage,
NULL::INTEGER AS salary_hay_grade,
NULL::VARCHAR(3) AS salary_currency,
NULL::INTEGER AS salary_yearly_gross_fixed,
NULL::INTEGER AS salary_yearly_gross_variable,
w.location AS employment_work_location,
NULL::VARCHAR AS employment_work_location_type,
NULL::INTEGER AS salary_monthly_gross_fixed,
NULL::INTEGER AS salary_yearly_fully_loaded_cost,
'hris' AS source
FROM latest_workers w
LEFT JOIN latest_positions p
ON w.user_id = p.assigned_employee_id
LEFT JOIN {{ ref('department') }} d
ON p.assigned_unit_id = d.department_hris_id
)
SELECT
row_number() OVER () AS id,
user_id::VARCHAR AS worker_hris_id,
first_name,
last_name,
date_of_birth,
gender,
nationality,
ethnicity,
degree_level,
degree_name,
address_line_1,
address_line_2,
address_zip,
address_city,
address_country,
phone_number,
driver_license,
employment_start,
employment_type,
employment_function_level,
employment_function_title,
employment_team,
employment_notice_period,
employment_cost_center,
employment_exit_type,
employment_exit_date,
performance_rating,
performance_date,
employment_manager_id,
employment_criticality,
employment_probation_status,
source,
employment_probation_end_date,
employment_department_path,
email,
employment_earliest_retirement_date,
employment_fte_percentage,
salary_hay_grade,
salary_currency,
salary_yearly_gross_fixed,
salary_yearly_gross_variable,
employment_work_location,
employment_work_location_type,
salary_monthly_gross_fixed,
salary_yearly_fully_loaded_cost
FROM joined_data