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

44 lines
1.1 KiB
SQL

{{
config(
materialized='table'
)
}}
with recursive
latest_departments as (
select *
from (
select *,
row_number() over (partition by id order by _sdc_received_at desc) as rn
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)
select
id as department_hris_id,
applicable_organization as name,
null::text as manager_id,
id::ltree as path, -- start path with own ID
NULL::VARCHAR AS org_view_model
from latest_departments
where parent_id = 'Sarens Group'
union all
-- Recursive part: join child departments
select
d.id as department_hris_id,
d.applicable_organization as name,
null::text as manager_id,
dt.path || d.id::text::ltree as path,
NULL::VARCHAR AS org_view_model
from latest_departments d
join department_tree dt
on d.parent_id = dt.department_hris_id
)
select * from department_tree