Skip to content

Commit

Permalink
feat: draftseedlots (#1473)
Browse files Browse the repository at this point in the history
Co-authored-by: Derek Roberts <[email protected]>
  • Loading branch information
ronrobb and DerekRoberts authored Aug 2, 2024
1 parent 492389a commit 3477c9a
Show file tree
Hide file tree
Showing 11 changed files with 335 additions and 137 deletions.
293 changes: 198 additions & 95 deletions sync/config/SQL/SPAR/POSTGRES_SEEDLOT_EXTRACT.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,104 +4,202 @@ WITH seedlot_coll_methods
(SELECT seedlot_number
, TO_CHAR(cone_collection_method_code,'FM00') cone_collection_method_code
, ROW_NUMBER() OVER (PARTITION BY seedlot_number ORDER BY entry_timestamp) rown
FROM spar.seedlot_collection_method)
FROM spar.seedlot_collection_method
WHERE seedlot_number = %(p_seedlot_number)s)
, draft_seedlots
AS
(select seedlot_number
, case when all_step_data->'extractionStorageStep'->'extraction'->'agency'->>'isInvalid' = 'false'
and all_step_data->'extractionStorageStep'->'extraction'->'locationCode'->>'isInvalid' = 'false'
then all_step_data->'extractionStorageStep'->'extraction'->'agency'->>'value'
else null
end as extrct_cli_number
, case when all_step_data->'extractionStorageStep'->'extraction'->'agency'->>'isInvalid' = 'false'
and all_step_data->'extractionStorageStep'->'extraction'->'locationCode'->>'isInvalid' = 'false'
then all_step_data->'extractionStorageStep'->'extraction'->'locationCode'->>'value'
else null
end as extrct_cli_locn_cd
, case when all_step_data->'interimStep'->'facilityType'->>'isInvalid' = 'false'
then all_step_data->'interimStep'->'facilityType'->>'value'
else null
end as interm_facility_code
, case when all_step_data->'orchardStep'->'orchards'->'primaryOrchard'->>'isInvalid' = 'false'
then all_step_data->'orchardStep'->'orchards'->'primaryOrchard'->'value'->>'code'
else null
end as orchard_id
, case when all_step_data->'orchardStep'->'orchards'->'secondaryOrchard'->>'isInvalid' = 'false'
then all_step_data->'orchardStep'->'orchards'->'secondaryOrchard'->'value'->>'code'
else null
end as secondary_orchard_id
, CAST(case when all_step_data->'collectionStep'->'startDate'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'startDate'->>'value'
else null
end AS DATE) as collection_start_date
, CAST(case when all_step_data->'collectionStep'->'endDate'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'endDate'->>'value'
else null
end AS DATE) as collection_end_date
, case when all_step_data->'collectionStep'->'collectorAgency'->>'isInvalid' = 'false'
and all_step_data->'collectionStep'->'locationCode'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'collectorAgency'->>'value'
else null
end as collection_cli_number
, case when all_step_data->'collectionStep'->'collectorAgency'->>'isInvalid' = 'false'
and all_step_data->'collectionStep'->'locationCode'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'locationCode'->>'value'
else null
end as collection_cli_locn_cd
, CAST(case when all_step_data->'collectionStep'->'volumeOfCones'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'volumeOfCones'->>'value'
else null
end as NUMERIC) as clctn_volume
, CAST(case when all_step_data->'collectionStep'->'numberOfContainers'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'numberOfContainers'->>'value'
else null
end as NUMERIC) as no_of_containers
, CAST(case when all_step_data->'collectionStep'->'volumePerContainers'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'volumePerContainers'->>'value'
else null
end as NUMERIC) as vol_per_container
, TO_CHAR(CAST(case when all_step_data->'collectionStep'->'selectedCollectionCodes'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'selectedCollectionCodes'->'value'->>0
else null
end AS NUMERIC),'FM00') as cone_collection_method_code
, TO_CHAR(CAST(case when all_step_data->'collectionStep'->'selectedCollectionCodes'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'selectedCollectionCodes'->'value'->>1
else null
end AS NUMERIC),'FM00') as cone_collection_method2_code
, case when all_step_data->'collectionStep'->'comments'->>'isInvalid' = 'false'
then all_step_data->'collectionStep'->'comments'->>'value'
else null
end as seedlot_comment
from spar.seedlot_registration_a_class_save
where seedlot_number = %(p_seedlot_number)s)
SELECT
s.applicant_client_number,
s.applicant_email_address,
s.applicant_locn_code AS applicant_client_locn,
s.approved_timestamp,
replace(s.approved_userid, '\', '@') approved_userid -- 'Replacing @ to \ for Provider@User
,CASE WHEN s.BC_SOURCE_IND THEN 'Y' ELSE 'N' END as BC_SOURCE_IND
,s.BEC_VERSION_ID
,s.BGC_SUBZONE_CODE
,s.BGC_ZONE_CODE
,case when s.BIOTECH_PROCESSES_IND = True then 'Y' when BIOTECH_PROCESSES_IND = False then 'N' else '' end as BIOTECH_PROCESSES_IND
,s.CLCTN_VOLUME
,s.collection_locn_code as COLLECTION_CLI_LOCN_CD
,s.collection_client_number as COLLECTION_CLI_NUMBER
,s.COLLECTION_ELEVATION
,s.COLLECTION_ELEVATION_MAX
,s.COLLECTION_ELEVATION_MIN
,s.COLLECTION_END_DATE
,s.COLLECTION_LATITUDE_CODE
,s.collection_latitude_deg as COLLECTION_LAT_DEG
,s.collection_latitude_min as COLLECTION_LAT_MIN
,s.collection_latitude_sec as COLLECTION_LAT_SEC
,s.COLLECTION_LONGITUDE_CODE
,s.collection_longitude_deg as COLLECTION_LONG_DEG
,s.collection_longitude_min as COLLECTION_LONG_MIN
,s.collection_longitude_sec as COLLECTION_LONG_SEC
,s.COLLECTION_START_DATE
,scm1.cone_collection_method_code
,scm2.cone_collection_method_code as CONE_COLLECTION_METHOD2_CODE
,s.CONTAMINANT_POLLEN_BV
,case when s.CONTROLLED_CROSS_IND = True then 'Y' when CONTROLLED_CROSS_IND = False then 'N' else '' end as CONTROLLED_CROSS_IND
,s.DECLARED_TIMESTAMP
,REPLACE(s.DECLARED_USERID,'\', '@') DECLARED_USERID -- 'Replacing @ to \ for Provider@User
,s.EFFECTIVE_POP_SIZE
,s.ELEVATION
,s.ELEVATION_MAX
,s.ELEVATION_MIN
,s.ENTRY_TIMESTAMP
,REPLACE(s.ENTRY_USERID,'\', '@') ENTRY_USERID -- 'Replacing @ to \ for Provider@User
,s.EXTRACTION_END_DATE
,s.EXTRACTION_ST_DATE
,s.extractory_client_number as EXTRCT_CLI_NUMBER
,s.extractory_locn_code as EXTRCT_CLI_LOCN_CD
,s.FEMALE_GAMETIC_MTHD_CODE
,s.GENETIC_CLASS_CODE
,s.INTERM_FACILITY_CODE
,s.interm_strg_locn_code as INTERM_STRG_CLIENT_LOCN
,s.INTERM_STRG_CLIENT_NUMBER
,s.INTERM_STRG_END_DATE
,s.INTERM_STRG_LOCN
,s.INTERM_STRG_ST_DATE
,s.LATITUDE_DEG_MAX
,s.LATITUDE_DEG_MIN
,s.LATITUDE_DEGREES
,s.LATITUDE_MIN_MAX
,s.LATITUDE_MIN_MIN
,s.LATITUDE_MINUTES
,s.LATITUDE_SEC_MAX
,s.LATITUDE_SEC_MIN
,s.LATITUDE_SECONDS
,s.LONGITUDE_DEG_MAX
,s.LONGITUDE_DEG_MIN
,s.LONGITUDE_DEGREES
,s.LONGITUDE_MIN_MAX
,s.LONGITUDE_MIN_MIN
,s.LONGITUDE_MINUTES
,s.LONGITUDE_SEC_MAX
,s.LONGITUDE_SEC_MIN
,s.LONGITUDE_SECONDS
,s.MALE_GAMETIC_MTHD_CODE
,s.NO_OF_CONTAINERS
,s.area_of_use_comment as ORCHARD_COMMENT
,prim.orchard_id
,sec.secondary_orchard_id
,case when s.POLLEN_CONTAMINATION_IND = True then 'Y' when POLLEN_CONTAMINATION_IND = False then 'N' else '' end as POLLEN_CONTAMINATION_IND
,s.POLLEN_CONTAMINATION_MTHD_CODE
,s.POLLEN_CONTAMINATION_PCT
,s.REVISION_COUNT
,s.SEED_PLAN_UNIT_ID
,s.SEEDLOT_COMMENT
,s.SEEDLOT_NUMBER
,s.SEEDLOT_SOURCE_CODE
,s.SEEDLOT_STATUS_CODE
,s.temporary_strg_locn_code as SEED_STORE_CLIENT_LOCN
,s.temporary_strg_client_number as SEED_STORE_CLIENT_NUMBER
,s.SMP_MEAN_BV_GROWTH
,s.SMP_PARENTS_OUTSIDE
,s.SMP_SUCCESS_PCT
,s.temporary_strg_end_date::date as TEMPORARY_STORAGE_END_DATE
,s.temporary_strg_start_date::date as TEMPORARY_STORAGE_START_DATE
,CASE WHEN s.TO_BE_REGISTRD_IND THEN 'Y' ELSE 'N' END AS TO_BE_REGISTRD_IND
,s.TOTAL_PARENT_TREES
,s.UPDATE_TIMESTAMP
,REPLACE(s.UPDATE_USERID,'\', '@') UPDATE_USERID -- 'Replacing @ to \ for Provider@User
,s.VARIANT
,s.VEGETATION_CODE
,s.VOL_PER_CONTAINER
,CASE WHEN s.bc_source_ind THEN 'Y' ELSE 'N' END as bc_source_ind
,S.bec_version_id
,S.bgc_subzone_code
,S.bgc_zone_code
,case when s.biotech_processes_ind = True then 'Y' when biotech_processes_ind = False then 'N' else '' end as biotech_processes_ind
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.clctn_volume
ELSE s.clctn_volume
END as clctn_volume
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.collection_cli_locn_cd
ELSE s.collection_locn_code
END as collection_cli_locn_cd
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.collection_cli_number
ELSE s.collection_client_number
END as collection_cli_number
,S.collection_elevation
,S.collection_elevation_max
,S.collection_elevation_min
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.collection_end_date
ELSE s.collection_end_date
END as collection_end_date
,s.collection_latitude_code
,s.collection_latitude_deg as collection_lat_deg
,s.collection_latitude_min as collection_lat_min
,s.collection_latitude_sec as collection_lat_sec
,s.collection_longitude_code
,s.collection_longitude_deg as collection_long_deg
,s.collection_longitude_min as collection_long_min
,s.collection_longitude_sec as collection_long_sec
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.collection_start_date
ELSE s.collection_start_date
END as collection_start_date
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.cone_collection_method_code
ELSE scm1.cone_collection_method_code
END as cone_collection_method_code
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.cone_collection_method2_code
ELSE scm2.cone_collection_method_code
END as cone_collection_method2_code
,s.contaminant_pollen_bv
,CASE WHEN s.controlled_cross_ind = True THEN 'Y' WHEN controlled_cross_ind = False THEN 'N' ELSE '' END as CONTROLLED_CROSS_IND
,s.declared_timestamp
,REPLACE(s.declared_userid,'\', '@') declared_userid -- 'Replacing @ to \ for Provider@User
,s.effective_pop_size
,s.elevation
,s.elevation_max
,s.elevation_min
,s.entry_timestamp
,REPLACE(s.entry_userid,'\', '@') entry_userid -- 'Replacing @ to \ for Provider@User
,S.extraction_end_date
,S.extraction_st_date
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.extrct_cli_number
ELSE s.extractory_client_number
END as extrct_cli_number
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.extrct_cli_locn_cd
ELSE s.extractory_locn_code
END as extrct_cli_locn_cd
,s.female_gametic_mthd_code
,S.genetic_class_code
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.interm_facility_code
ELSE s.interm_facility_code
END as interm_facility_code
,s.interm_strg_locn_code as interm_strg_client_locn
,S.interm_strg_client_number
,S.interm_strg_end_date
,S.interm_strg_locn
,S.interm_strg_st_date
,S.latitude_deg_max
,S.latitude_deg_min
,S.latitude_degrees
,S.latitude_min_max
,S.latitude_min_min
,S.latitude_minutes
,S.latitude_sec_max
,S.latitude_sec_min
,S.latitude_seconds
,S.longitude_deg_max
,S.longitude_deg_min
,S.longitude_degrees
,S.longitude_min_max
,S.longitude_min_min
,S.longitude_minutes
,S.longitude_sec_max
,S.longitude_sec_min
,S.longitude_seconds
,S.male_gametic_mthd_code
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.no_of_containers
ELSE s.no_of_containers
END no_of_containers
,s.area_of_use_comment as orchard_comment
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.orchard_id
ELSE prim.orchard_id
END orchard_id
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.secondary_orchard_id
ELSE sec.secondary_orchard_id
END secondary_orchard_id
,CASE WHEN s.pollen_contamination_ind = True THEN 'Y' WHEN pollen_contamination_ind = False THEN 'N' ELSE '' END as pollen_contamination_ind
,s.pollen_contamination_mthd_code
,s.pollen_contamination_pct
,s.revision_count
,s.seed_plan_unit_id
,s.seedlot_comment
,s.seedlot_number
,s.seedlot_source_code
,s.seedlot_status_code
,s.temporary_strg_locn_code as seed_store_client_locn
,s.temporary_strg_client_number as seed_store_client_number
,s.smp_mean_bv_growth
,s.smp_parents_outside
,s.smp_success_pct
,s.temporary_strg_end_date::date as temporary_storage_end_date
,s.temporary_strg_start_date::date as temporary_storage_start_date
,CASE WHEN s.to_be_registrd_ind THEN 'Y' Else 'N' END as to_be_registrd_ind
,s.total_parent_trees
,s.update_timestamp
,REPLACE(s.update_userid,'\', '@') update_userid -- 'Replacing @ to \ for Provider@User
,s.variant
,s.vegetation_code
,CASE WHEN s.seedlot_status_code = 'PND' THEN drft.vol_per_container
ELSE s.vol_per_container
END vol_per_container
FROM spar.seedlot s
LEFT OUTER JOIN seedlot_coll_methods scm1
ON (scm1.seedlot_number = s.seedlot_number AND scm1.rown = 1)
Expand All @@ -110,14 +208,19 @@ LEFT OUTER JOIN seedlot_coll_methods scm2
LEFT OUTER JOIN (SELECT po.seedlot_number
, po.orchard_id
FROM spar.seedlot_orchard po
WHERE po.primary_ind = 'Y') prim
WHERE po.primary_ind = True) prim
ON prim.seedlot_number = s.seedlot_number
LEFT OUTER JOIN (SELECT DISTINCT
so.seedlot_number
, FIRST_VALUE(so.orchard_id) OVER (PARTITION BY so.seedlot_number
ORDER BY so.entry_timestamp) secondary_orchard_id
FROM spar.seedlot_orchard so
WHERE so.primary_ind = 'N') sec
WHERE so.primary_ind = False) sec
ON sec.seedlot_number = s.seedlot_number
LEFT OUTER JOIN spar.active_orchard_spu ospu
ON ospu.orchard_id = prim.orchard_id
AND ospu.active_ind = True
LEFT OUTER JOIN draft_seedlots drft
ON drft.seedlot_number = s.seedlot_number
WHERE s.seedlot_number = %(p_seedlot_number)s
order by seedlot_number desc
ORDER BY s.seedlot_number DESC
24 changes: 14 additions & 10 deletions sync/config/SQL/SPAR/POSTGRES_SEEDLOT_GENETIC_WORTH_EXTRACT.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,17 @@
SELECT
seedlot_number
, genetic_worth_code
, genetic_quality_value genetic_worth_rtng
, REPLACE(entry_userid,'\', '@') as entry_userid
, entry_timestamp
, REPLACE(update_userid,'\', '@') as update_userid
, update_timestamp
, revision_count
sgw.seedlot_number
, sgw.genetic_worth_code
, sgw.genetic_quality_value genetic_worth_rtng
, REPLACE(sgw.entry_userid,'\', '@') as entry_userid
, sgw.entry_timestamp
, REPLACE(sgw.update_userid,'\', '@') as update_userid
, sgw.update_timestamp
, sgw.revision_count
FROM spar.seedlot_genetic_worth sgw
JOIN spar.seedlot s
ON s.seedlot_number = sgw.seedlot_number
WHERE sgw.seedlot_number = %(p_seedlot_number)s
ORDER BY seedlot_number
, genetic_worth_code
AND s.seedlot_status_code != 'PND'
ORDER BY sgw.seedlot_number
, sgw.genetic_worth_code
Loading

0 comments on commit 3477c9a

Please sign in to comment.