-
Notifications
You must be signed in to change notification settings - Fork 35
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge branch 'main' into MAIN-B-22668
- Loading branch information
Showing
147 changed files
with
13,374 additions
and
558 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,3 +1,4 @@ | ||
# This is the functions(procedures) migrations manifest. | ||
# If a migration is not recorded here, then it will error. | ||
# Naming convention: fn_some_function.up.sql running <generate-ddl-migration some_function functions> will create this file. | ||
20250223023132_fn_get_counseling_offices.up.sql |
171 changes: 171 additions & 0 deletions
171
migrations/app/ddl_migrations/ddl_functions/20250223023132_fn_get_counseling_offices.up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,171 @@ | ||
--B-22660 Daniel Jordan added get_duty_location_info | ||
CREATE OR REPLACE FUNCTION get_duty_location_info(p_duty_location_id UUID) | ||
RETURNS TABLE (duty_addr_id UUID, is_oconus BOOLEAN) | ||
LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
RETURN QUERY | ||
SELECT dl.address_id, a.is_oconus | ||
FROM duty_locations dl | ||
JOIN addresses a ON a.id = dl.address_id | ||
WHERE dl.id = p_duty_location_id; | ||
END; | ||
$$; | ||
|
||
--B-22660 Daniel Jordan added get_service_affiliation | ||
CREATE OR REPLACE FUNCTION get_service_affiliation(p_service_member_id UUID) | ||
RETURNS TEXT | ||
LANGUAGE plpgsql AS $$ | ||
DECLARE | ||
service_affiliation TEXT; | ||
BEGIN | ||
SELECT affiliation INTO service_affiliation | ||
FROM service_members | ||
WHERE id = p_service_member_id; | ||
|
||
RETURN service_affiliation; | ||
END; | ||
$$; | ||
|
||
--B-22660 Daniel Jordan added get_department_indicator | ||
CREATE OR REPLACE FUNCTION get_department_indicator(p_service_affiliation TEXT) | ||
RETURNS TEXT | ||
LANGUAGE plpgsql AS $$ | ||
DECLARE | ||
dept_indicator TEXT; | ||
BEGIN | ||
IF p_service_affiliation IN ('AIR_FORCE', 'SPACE_FORCE') THEN | ||
dept_indicator := 'AIR_AND_SPACE_FORCE'; | ||
ELSIF p_service_affiliation IN ('NAVY', 'MARINES') THEN | ||
dept_indicator := 'NAVY_AND_MARINES'; | ||
ELSIF p_service_affiliation = 'ARMY' THEN | ||
dept_indicator := 'ARMY'; | ||
ELSIF p_service_affiliation = 'COAST_GUARD' THEN | ||
dept_indicator := 'COAST_GUARD'; | ||
ELSE | ||
RAISE EXCEPTION 'Invalid affiliation: %', p_service_affiliation; | ||
END IF; | ||
|
||
RETURN dept_indicator; | ||
END; | ||
$$; | ||
|
||
--B-22660 Daniel Jordan added get_gbloc_indicator | ||
CREATE OR REPLACE FUNCTION get_gbloc_indicator(p_duty_addr_id UUID, p_dept_indicator TEXT) | ||
RETURNS TEXT | ||
LANGUAGE plpgsql AS $$ | ||
DECLARE | ||
gbloc_indicator TEXT; | ||
BEGIN | ||
SELECT j.code INTO gbloc_indicator | ||
FROM addresses a | ||
JOIN v_locations v ON a.us_post_region_cities_id = v.uprc_id | ||
JOIN re_oconus_rate_areas o ON v.uprc_id = o.us_post_region_cities_id | ||
JOIN re_rate_areas r ON o.rate_area_id = r.id | ||
JOIN gbloc_aors g ON o.id = g.oconus_rate_area_id | ||
JOIN jppso_regions j ON g.jppso_regions_id = j.id | ||
WHERE a.id = p_duty_addr_id | ||
AND (g.department_indicator = p_dept_indicator OR g.department_indicator IS NULL) | ||
LIMIT 1; | ||
|
||
IF gbloc_indicator IS NULL THEN | ||
RAISE EXCEPTION 'Cannot determine GBLOC for duty location'; | ||
END IF; | ||
|
||
RETURN gbloc_indicator; | ||
END; | ||
$$; | ||
|
||
--B-22660 Daniel Jordan added fetch_counseling_offices_for_oconus | ||
CREATE OR REPLACE FUNCTION fetch_counseling_offices_for_oconus(p_duty_location_id UUID, p_gbloc_indicator TEXT) | ||
RETURNS TABLE (id UUID, name TEXT) | ||
LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
RETURN QUERY | ||
SELECT toff.id, toff.name | ||
FROM duty_locations dl | ||
JOIN addresses a ON dl.address_id = a.id | ||
JOIN v_locations v ON (a.us_post_region_cities_id = v.uprc_id OR v.uprc_id IS NULL) | ||
AND a.country_id = v.country_id | ||
JOIN re_oconus_rate_areas r ON r.us_post_region_cities_id = v.uprc_id | ||
JOIN gbloc_aors ga ON ga.oconus_rate_area_id = r.id | ||
JOIN jppso_regions j ON ga.jppso_regions_id = j.id | ||
JOIN transportation_offices toff ON j.code = toff.gbloc | ||
JOIN addresses toff_addr ON toff.address_id = toff_addr.id | ||
LEFT JOIN zip3_distances zd | ||
ON ( | ||
(substring(a.postal_code, 1, 3) = zd.from_zip3 AND substring(toff_addr.postal_code, 1, 3) = zd.to_zip3) | ||
OR | ||
(substring(a.postal_code, 1, 3) = zd.to_zip3 AND substring(toff_addr.postal_code, 1, 3) = zd.from_zip3) | ||
) | ||
WHERE dl.provides_services_counseling = true | ||
AND dl.id = p_duty_location_id | ||
AND j.code = p_gbloc_indicator | ||
AND toff.provides_ppm_closeout = true | ||
ORDER BY COALESCE(zd.distance_miles, 0) ASC; | ||
END; | ||
$$; | ||
|
||
--B-22660 Daniel Jordan added fetch_counseling_offices_for_conus | ||
CREATE OR REPLACE FUNCTION fetch_counseling_offices_for_conus(p_duty_location_id UUID) | ||
RETURNS TABLE (id UUID, name TEXT) | ||
LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
RETURN QUERY | ||
SELECT | ||
toff.id, | ||
toff.name | ||
FROM postal_code_to_gblocs pcg | ||
JOIN addresses a ON pcg.postal_code = a.postal_code | ||
JOIN duty_locations dl ON a.id = dl.address_id | ||
JOIN transportation_offices toff ON pcg.gbloc = toff.gbloc | ||
JOIN addresses toff_addr ON toff.address_id = toff_addr.id | ||
JOIN duty_locations d2 ON toff.id = d2.transportation_office_id | ||
JOIN re_us_post_regions rup ON toff_addr.postal_code = rup.uspr_zip_id | ||
LEFT JOIN zip3_distances zd | ||
ON ( | ||
(substring(a.postal_code, 1, 3) = zd.from_zip3 AND substring(toff_addr.postal_code, 1, 3) = zd.to_zip3) | ||
OR | ||
(substring(a.postal_code, 1, 3) = zd.to_zip3 AND substring(toff_addr.postal_code, 1, 3) = zd.from_zip3) | ||
) | ||
WHERE dl.provides_services_counseling = true | ||
AND dl.id = p_duty_location_id | ||
AND d2.provides_services_counseling = true | ||
GROUP BY toff.id, toff.name, zd.distance_miles | ||
ORDER BY COALESCE(zd.distance_miles, 0), toff.name ASC; | ||
END; | ||
$$; | ||
|
||
--B-22660 Daniel Jordan added get_counseling_offices | ||
CREATE OR REPLACE FUNCTION get_counseling_offices( | ||
p_duty_location_id UUID, | ||
p_service_member_id UUID | ||
) | ||
RETURNS TABLE (id UUID, name TEXT) | ||
LANGUAGE plpgsql AS $$ | ||
DECLARE | ||
is_address_oconus BOOLEAN; | ||
duty_address_id UUID; | ||
service_affiliation TEXT; | ||
dept_indicator TEXT; | ||
gbloc_indicator TEXT; | ||
BEGIN | ||
|
||
SELECT duty_addr_id, is_oconus INTO duty_address_id, is_address_oconus | ||
FROM get_duty_location_info(p_duty_location_id); | ||
|
||
IF duty_address_id IS NULL THEN | ||
RAISE EXCEPTION 'Duty location % not found when searching for counseling offices', p_duty_location_id; | ||
END IF; | ||
|
||
IF is_address_oconus THEN | ||
service_affiliation := get_service_affiliation(p_service_member_id); | ||
dept_indicator := get_department_indicator(service_affiliation); | ||
|
||
gbloc_indicator := get_gbloc_indicator(duty_address_id, dept_indicator); | ||
|
||
RETURN QUERY SELECT * FROM fetch_counseling_offices_for_oconus(p_duty_location_id, gbloc_indicator); | ||
ELSE | ||
RETURN QUERY SELECT * FROM fetch_counseling_offices_for_conus(p_duty_location_id); | ||
END IF; | ||
END; | ||
$$; |
3 changes: 3 additions & 0 deletions
3
migrations/app/ddl_migrations/ddl_tables/20250224200700_tbl_ppm_shipments.up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,3 @@ | ||
-- B-22653 Daniel Jordan add ppm_type column to ppm_shipments | ||
ALTER TABLE ppm_shipments | ||
ADD COLUMN IF NOT EXISTS ppm_type ppm_shipment_type NOT NULL DEFAULT 'INCENTIVE_BASED'; |
11 changes: 11 additions & 0 deletions
11
migrations/app/ddl_migrations/ddl_types/20250224202726_ty_ppm_shipment_type.up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,11 @@ | ||
-- B-22653 Daniel Jordan add ppm_shipment_type | ||
DO $$ | ||
BEGIN | ||
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'ppm_shipment_type') THEN | ||
CREATE TYPE ppm_shipment_type AS ENUM ( | ||
'INCENTIVE_BASED', | ||
'ACTUAL_EXPENSE', | ||
'SMALL_PACKAGE' | ||
); | ||
END IF; | ||
END $$; |
2 changes: 2 additions & 0 deletions
2
migrations/app/ddl_migrations/ddl_types/20250224202738_ty_moving_expenses_type.up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
-- B-22653 Daniel Jordan update moving_expense_type to include SMALL_PACKAGE | ||
ALTER TYPE moving_expense_type ADD VALUE IF NOT EXISTS 'SMALL_PACKAGE'; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,3 +1,4 @@ | ||
# This is the tables migrations manifest. | ||
# If a migration is not recorded here, then it will error. | ||
# Naming convention: tbl_some_table.up.sql running <generate-ddl-migration some_table tables> will create this file. | ||
20250224200700_tbl_ppm_shipments.up.sql |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,3 +1,5 @@ | ||
# This is the types migrations manifest. | ||
# If a migration is not recorded here, then it will error. | ||
# Naming convention: ty_some_type.up.sql running <generate-ddl-migration some_type types> will create this file. | ||
20250224202726_ty_ppm_shipment_type.up.sql | ||
20250224202738_ty_moving_expenses_type.up.sql |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
Oops, something went wrong.