Skip to content

Commit

Permalink
Model changes include source and refs
Browse files Browse the repository at this point in the history
  • Loading branch information
vishreddy01 committed Mar 1, 2024
1 parent 0e820ea commit ba47e01
Show file tree
Hide file tree
Showing 10 changed files with 130 additions and 73 deletions.
20 changes: 10 additions & 10 deletions pmt/dbt/pmt_dbt/snapshots/dal/extract_permits.sql
Original file line number Diff line number Diff line change
Expand Up @@ -54,51 +54,51 @@ with extract_data as (
fpt.permit_type_code,
ptp.permit_type_description,
fpt.unqid
FROM pmt_dpl.fact_permits fpt
left join pmt_dpl.dim_authorization_status ast
FROM {{ ref('fact_permits') }} fpt
left join {{ ref('dim_authorization_status') }} ast
on (fpt.authorization_status_code = ast.authorization_status_code
and ast.src_sys_code = fpt.src_sys_code
and fpt.dbt_valid_to is null
and ast.dbt_valid_to is null)
left join pmt_dpl.dim_business_area bar
left join {{ ref('dim_business_area') }} bar
on (bar.business_area_code = fpt.business_area_code
and bar.src_sys_code = 'CORP'
and fpt.dbt_valid_to is null
and bar.dbt_valid_to is null)
left join pmt_dpl.dim_ministry mnt
left join {{ ref('dim_ministry') }} mnt
on (mnt.ministry_code = fpt.ministry_code
and mnt.src_sys_code = 'CORP'
and fpt.dbt_valid_to is null
and mnt.dbt_valid_to is null)
left join pmt_dpl.dim_org org
left join {{ ref('dim_org') }} org
on (org.org_unit_code = fpt.permit_org_unit_code
and org.src_sys_code = 'CORP'
and fpt.dbt_valid_to is null
and org.dbt_valid_to is null)
left join pmt_dpl.dim_permit_status pst
left join {{ ref('dim_permit_status') }} pst
on (pst.permit_status_code = fpt.permit_status_code
and pst.src_sys_code = fpt.src_sys_code
and fpt.dbt_valid_to is null
and pst.dbt_valid_to is null)
left join pmt_dpl.dim_permit_type ptp
left join {{ ref('dim_permit_type') }} ptp
on (ptp.permit_type_code = fpt.permit_type_code
and ptp.src_sys_code = fpt.src_sys_code
and fpt.dbt_valid_to is null
and ptp.dbt_valid_to is null)
left join pmt_dpl.dim_project prj
left join {{ ref('dim_project') }} prj
on (prj.project_id = fpt.project_id
and prj.src_sys_code = fpt.src_sys_code
and fpt.dbt_valid_to is null
and prj.dbt_valid_to is null)
left join pmt_dpl.dim_org atsorg
left join {{ ref('dim_org') }} atsorg
on (replace(atsorg.org_unit_description,' Natural Resource Region','') = case when prj.project_region_description = 'Kootenay Boundary' then 'Kootenay-Boundary'
when prj.project_region_description ='Thompson Okanagan' then 'Thompson-Okanagan'
when prj.project_region_description ='North East' then 'Northeast'
else prj.project_region_description end
and atsorg.src_sys_code = 'CORP'
and atsorg.org_unit_description !~'OBSOLETE' and atsorg.org_unit_description like '%Natural Resource Region%'
and atsorg.dbt_valid_to is null)
left join pmt_dpl.dim_source_system ss
left join {{ ref('dim_source_system') }} ss
on (ss.src_sys_code = fpt.src_sys_code
and fpt.dbt_valid_to is null
and ss.dbt_valid_to is null)
Expand Down
10 changes: 5 additions & 5 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_authorization_status.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ Select 'ATS' as src_sys_code
,aasc.authorization_status_code as authorization_status_code
,aasc.name as authorization_status_description
,'ATS' || '|'|| coalesce(cast(aasc.authorization_status_code as varchar),'~') as unqid
from fdw_ods_ats_replication.ats_authorization_status_codes aasc
from {{source ('ats','ats_authorization_status_codes') }} aasc
where 1=1
),
fta_data as (
Expand All @@ -25,24 +25,24 @@ fta_data as (
,tasc.tenure_application_state_code as authorization_status_code
,tasc.description AS authorization_status_description
,'FTA' || '|'|| coalesce(cast(tasc.tenure_application_state_code as varchar),'~') as unqid
FROM fdw_ods_fta_replication.tenure_application_state_code tasc
FROM {{source ('fta','tenure_application_state_code') }} tasc
)
,rrs_rp_data as (
Select distinct
'RRS_RP' as src_sys_code
,rasc.road_application_status_code as authorization_status_code
,rasc.description AS authorization_status_description
,'RRS_RP' || '|'|| coalesce(cast(rasc.road_application_status_code as varchar),'~') as unqid
FROM fdw_ods_rrs_replication.road_application_status_code rasc
FROM {{source ('rrs','road_application_status_code') }} rasc
)
,rrs_rup_data as (
Select distinct
'RRS_RUP' as src_sys_code
,rs.submission_status_code as authorization_status_code
,ssc.description AS authorization_status_description
,'RRS_RUP' || '|'|| coalesce(cast(rs.submission_status_code as varchar),'~') as unqid
FROM fdw_ods_rrs_replication.road_submission rs
left join fdw_ods_rrs_replication.submission_status_code ssc ON (rs.submission_status_code = ssc.submission_status_code)
FROM {{source ('rrs','road_submission') }} rs
left join {{source ('rrs','submission_status_code') }} ssc ON (rs.submission_status_code = ssc.submission_status_code)
where 1=1
and rs.road_submission_type_code = 'RUP'
and rs.submission_status_code is not null
Expand Down
6 changes: 4 additions & 2 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_location.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,8 +16,10 @@ with ats_data as
'ATS' as src_sys_code
,proj.location as location_code
,'ATS' || '|'|| coalesce(cast(proj.location as varchar),'~') as unqid
from fdw_ods_ats_replication.ats_projects proj
inner join fdw_ods_ats_replication.ats_managing_fcbc_regions amfr
--from fdw_ods_ats_replication.ats_projects proj
--inner join fdw_ods_ats_replication.ats_managing_fcbc_regions amfr
from {{ source('ats','ats_projects') }} proj
inner join {{ source('ats','ats_managing_fcbc_regions') }} amfr
on (proj.managing_fcbc_region_id = amfr.managing_fcbc_region_id)
where proj.project_status_code = '1'
)
Expand Down
6 changes: 3 additions & 3 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_ministry.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,10 +35,10 @@ with corp_data as (
WHEN ats.authorization_instrument_id = ANY (ARRAY[1282, 1281, 1343, 1344, 1361, 1301, 1302, 1303, 1304, 1283, 60, 1341, 1305, 1306, 1342, 21, 107]) THEN 'ENV'
ELSE NULL
END as varchar),'~') as unqid
from fdw_ods_ats_replication.ats_authorizations ats
LEFT JOIN fdw_ods_ats_replication.ats_authorization_status_codes aasc
from {{ source('ats','ats_authorizations') }} ats
LEFT JOIN {{ source('ats','ats_authorization_status_codes') }} aasc
ON(ats.authorization_status_code = aasc.authorization_status_code)
LEFT JOIN fdw_ods_ats_replication.ats_authorization_instruments aai
LEFT JOIN {{ source('ats','ats_authorization_instruments') }} aai
ON(ats.authorization_instrument_id = aai.authorization_instrument_id)
where 1=1
AND aasc.authorization_status_code <> '1'
Expand Down
6 changes: 3 additions & 3 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_org.sql
Original file line number Diff line number Diff line change
Expand Up @@ -27,9 +27,9 @@ with corp_data as (
when org.rollup_dist_code in ('DSC','DSQ','DCK','DNI','DSI','DQC','DCR') then 'Coast Area' end as roll_up_area_description
-- Combine multiple keys into a single composite_key
,'CORP' || '|'|| coalesce(cast(org.org_unit_code as varchar),'~') as unqid
from fdw_ods_fta_replication.org_unit org
left join fdw_ods_fta_replication.org_unit reg on (org.rollup_region_code = reg.org_unit_code)
left join fdw_ods_fta_replication.org_unit rdis on (org.rollup_dist_code = rdis.org_unit_code)
from {{ source('fta','org_unit') }} org
left join {{ source('fta','org_unit') }} reg on (org.rollup_region_code = reg.org_unit_code)
left join {{ source('fta','org_unit') }} rdis on (org.rollup_dist_code = rdis.org_unit_code)
)
--insert into pmt_dpl.dim_org
select * from corp_data
Expand Down
4 changes: 2 additions & 2 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_permit_status.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,15 +23,15 @@ with ats_data as (
,hsc.harvest_auth_status_code as permit_status_code
,hsc.description as permit_status_description
,'FTA' || '|'|| coalesce(cast(hsc.harvest_auth_status_code as varchar),'~') as unqid
FROM fdw_ods_fta_replication.harvest_auth_status_code hsc
FROM {{ source('fta','harvest_auth_status_code') }} hsc
)
,rrs_rp_data as (
Select distinct
'RRS_RP' as src_sys_code
,rtsc.road_tenure_status_code as permit_status_code
,rtsc.description AS permit_status_description
,'RRS_RP' || '|'|| coalesce(cast(rtsc.road_tenure_status_code as varchar),'~') as unqid
FROM fdw_ods_rrs_replication.road_tenure_status_code rtsc
FROM {{ source('rrs','road_tenure_status_code') }} rtsc
)
,rrs_rup_data as (
Select distinct
Expand Down
8 changes: 4 additions & 4 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_permit_type.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ with ats_data as (
,aai.authorization_instrument_id::varchar(25) as permit_type_code
,aai.authorization_instrument_name as permit_type_description
,'ATS' || '|'|| coalesce(cast(aai.authorization_instrument_id as varchar),'~') as unqid
from fdw_ods_ats_replication.ats_authorization_instruments aai
from {{source ('ats','ats_authorization_instruments') }} aai
where 1=1
)
,
Expand All @@ -25,8 +25,8 @@ fta_data as (
,pfu.file_type_code::varchar(25) AS permit_type_code
, ftc.description AS permit_type_description
,'FTA' || '|'|| coalesce(cast(pfu.file_type_code as varchar(25)),'~') as unqid
from fdw_ods_fta_replication.prov_forest_use pfu
left join fdw_ods_fta_replication.file_type_code ftc
from {{source ('fta','prov_forest_use') }} pfu
left join {{source ('fta','file_type_code') }} ftc
ON (ftc.file_type_code = pfu.file_type_code)
)
,
Expand All @@ -35,7 +35,7 @@ rrs_rp_data as (
,rttc.road_tenure_type_code as permit_type_code
,rttc.description as permit_type_description
,'RRS_RP' || '|'|| coalesce(cast(rttc.road_tenure_type_code as varchar(25)),'~') as unqid
from fdw_ods_rrs_replication.road_tenure_type_code rttc
from {{source ('rrs','road_tenure_type_code') }} rttc
)
,
rrs_rup_data as (
Expand Down
4 changes: 2 additions & 2 deletions pmt/dbt/pmt_dbt/snapshots/dpl/dim_project.sql
Original file line number Diff line number Diff line change
Expand Up @@ -20,8 +20,8 @@ with ats_data as (
prj.project_status_code,
amfr.region_name as project_region_description,
'ATS' || '|'|| coalesce(cast(prj.project_id as varchar),'~') as unqid
from fdw_ods_ats_replication.ats_projects prj
left join fdw_ods_ats_replication.ats_managing_fcbc_regions amfr ---dim_regions
from {{source ('ats','ats_projects') }} prj
left join {{source ('ats','ats_managing_fcbc_regions') }} amfr ---dim_regions
on (prj.managing_fcbc_region_id = amfr.managing_fcbc_region_id )
where 1=1
and prj.project_status_code = '1'
Expand Down
Loading

0 comments on commit ba47e01

Please sign in to comment.