Skip to content

Commit

Permalink
Merge pull request #14388 from transcom/B-21583-gbloc-AK-moves
Browse files Browse the repository at this point in the history
B-21583 - update code to calculate gbloc for AK
  • Loading branch information
pambecker authored Feb 7, 2025
2 parents 3ada8c6 + 197ae63 commit 9976287
Show file tree
Hide file tree
Showing 32 changed files with 2,276 additions and 774 deletions.
3 changes: 3 additions & 0 deletions migrations/app/migrations_manifest.txt
Original file line number Diff line number Diff line change
Expand Up @@ -1059,6 +1059,7 @@
20241216190428_update_get_zip_code_function_and_update_pricing_proc.up.sql
20241217163231_update_duty_locations_bad_zips.up.sql
20241217180136_add_AK_zips_to_zip3_distances.up.sql
20241217191012_update_move_to_gbloc_for_ak.up.sql
20241218201833_add_PPPO_BASE_ELIZABETH.up.sql
20241218204620_add_international_nts_service_items.up.sql
20241220171035_add_additional_AK_zips_to_zip3_distances.up.sql
Expand All @@ -1071,6 +1072,8 @@
20241230190638_remove_AK_zips_from_zip3.up.sql
20241230190647_add_missing_AK_zips_to_zip3_distances.up.sql
20241231155337_add_payment_params_for_international_shuttle.up.sql
20250103130619_revert_data_change_for_gbloc_for_ak.up.sql
20250103142533_update_postal_codes_and_gblocs_for_ak.up.sql
20250103180420_update_pricing_proc_to_use_local_price_variable.up.sql
20250110001339_update_nts_release_enum_name.up.sql
20250110153428_add_shipment_address_updates_to_move_history.up.sql
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
delete from postal_code_to_gblocs where postal_code in (
select uspr_zip_id from v_locations where state = 'AK');

drop view move_to_gbloc;
CREATE OR REPLACE VIEW move_to_gbloc AS
SELECT move_id, gbloc FROM (
SELECT DISTINCT ON (sh.move_id) sh.move_id, s.affiliation,
COALESCE(pctg.gbloc, coalesce(pctg_oconus_bos.gbloc, coalesce(pctg_oconus.gbloc, pctg_ppm.gbloc))) AS gbloc
FROM mto_shipments sh
JOIN moves m ON sh.move_id = m.id
JOIN orders o on m.orders_id = o.id
JOIN service_members s on o.service_member_id = s.id
LEFT JOIN ( SELECT a.id AS address_id,
pctg_1.gbloc, pctg_1.postal_code
FROM addresses a
JOIN postal_code_to_gblocs pctg_1 ON a.postal_code::text = pctg_1.postal_code::text) pctg ON pctg.address_id = sh.pickup_address_id
LEFT JOIN ( SELECT ppm.shipment_id,
pctg_1.gbloc
FROM ppm_shipments ppm
JOIN addresses ppm_address ON ppm.pickup_postal_address_id = ppm_address.id
JOIN postal_code_to_gblocs pctg_1 ON ppm_address.postal_code::text = pctg_1.postal_code::text) pctg_ppm ON pctg_ppm.shipment_id = sh.id
LEFT JOIN ( SELECT a.id AS address_id,
cast(jr.code as varchar) AS gbloc, ga.department_indicator
FROM addresses a
JOIN re_oconus_rate_areas ora ON a.us_post_region_cities_id = ora.us_post_region_cities_id
JOIN gbloc_aors ga ON ora.id = ga.oconus_rate_area_id
JOIN jppso_regions jr ON ga.jppso_regions_id = jr.id
) pctg_oconus_bos ON pctg_oconus_bos.address_id = sh.pickup_address_id
and case when s.affiliation = 'AIR_FORCE' THEN 'AIR_AND_SPACE_FORCE'
when s.affiliation = 'SPACE_FORCE' THEN 'AIR_AND_SPACE_FORCE'
when s.affiliation = 'NAVY' THEN 'NAVY_AND_MARINES'
when s.affiliation = 'MARINES' THEN 'NAVY_AND_MARINES'
else s.affiliation
end = pctg_oconus_bos.department_indicator
LEFT JOIN ( SELECT a.id AS address_id,
cast(pctg_1.code as varchar) AS gbloc, ga.department_indicator
FROM addresses a
JOIN re_oconus_rate_areas ora ON a.us_post_region_cities_id = ora.us_post_region_cities_id
JOIN gbloc_aors ga ON ora.id = ga.oconus_rate_area_id
JOIN jppso_regions pctg_1 ON ga.jppso_regions_id = pctg_1.id
) pctg_oconus ON pctg_oconus.address_id = sh.pickup_address_id and pctg_oconus.department_indicator is null
WHERE sh.deleted_at IS NULL
ORDER BY sh.move_id, sh.created_at) as m;

Large diffs are not rendered by default.

Original file line number Diff line number Diff line change
@@ -0,0 +1,159 @@
delete from postal_code_to_gblocs where postal_code in (
select uspr_zip_id from v_locations where state = 'AK');

drop view move_to_gbloc;
CREATE OR REPLACE VIEW move_to_gbloc AS
SELECT move_id, gbloc FROM (
SELECT DISTINCT ON (sh.move_id) sh.move_id, s.affiliation,
COALESCE(pctg.gbloc, coalesce(pctg_oconus_bos.gbloc, coalesce(pctg_oconus.gbloc, pctg_ppm.gbloc))) AS gbloc
FROM mto_shipments sh
JOIN moves m ON sh.move_id = m.id
JOIN orders o on m.orders_id = o.id
JOIN service_members s on o.service_member_id = s.id
LEFT JOIN ( SELECT a.id AS address_id,
pctg_1.gbloc, pctg_1.postal_code
FROM addresses a
JOIN postal_code_to_gblocs pctg_1 ON a.postal_code::text = pctg_1.postal_code::text) pctg ON pctg.address_id = sh.pickup_address_id
LEFT JOIN ( SELECT ppm.shipment_id,
pctg_1.gbloc
FROM ppm_shipments ppm
JOIN addresses ppm_address ON ppm.pickup_postal_address_id = ppm_address.id
JOIN postal_code_to_gblocs pctg_1 ON ppm_address.postal_code::text = pctg_1.postal_code::text) pctg_ppm ON pctg_ppm.shipment_id = sh.id
LEFT JOIN ( SELECT a.id AS address_id,
cast(jr.code as varchar) AS gbloc, ga.department_indicator
FROM addresses a
JOIN re_oconus_rate_areas ora ON a.us_post_region_cities_id = ora.us_post_region_cities_id
JOIN gbloc_aors ga ON ora.id = ga.oconus_rate_area_id
JOIN jppso_regions jr ON ga.jppso_regions_id = jr.id
) pctg_oconus_bos ON pctg_oconus_bos.address_id = sh.pickup_address_id
and case when s.affiliation = 'AIR_FORCE' THEN 'AIR_AND_SPACE_FORCE'
when s.affiliation = 'SPACE_FORCE' THEN 'AIR_AND_SPACE_FORCE'
when s.affiliation = 'NAVY' THEN 'NAVY_AND_MARINES'
when s.affiliation = 'MARINES' THEN 'NAVY_AND_MARINES'
else s.affiliation
end = pctg_oconus_bos.department_indicator
LEFT JOIN ( SELECT a.id AS address_id,
cast(pctg_1.code as varchar) AS gbloc, ga.department_indicator
FROM addresses a
JOIN re_oconus_rate_areas ora ON a.us_post_region_cities_id = ora.us_post_region_cities_id
JOIN gbloc_aors ga ON ora.id = ga.oconus_rate_area_id
JOIN jppso_regions pctg_1 ON ga.jppso_regions_id = pctg_1.id
) pctg_oconus ON pctg_oconus.address_id = sh.pickup_address_id and pctg_oconus.department_indicator is null
WHERE sh.deleted_at IS NULL
ORDER BY sh.move_id, sh.created_at) as m;


DROP FUNCTION IF EXISTS get_address_gbloc;

CREATE OR REPLACE FUNCTION public.get_address_gbloc(
address_id UUID,
affiliation TEXT,
OUT gbloc TEXT
)
RETURNS TEXT AS $$
DECLARE
is_oconus BOOLEAN;
v_count INT;
v_bos_count INT;
v_dept_ind TEXT;
BEGIN
is_oconus := get_is_oconus(address_id);

IF affiliation in ('AIR_FORCE','SPACE_FORCE') THEN
v_dept_ind := 'AIR_AND_SPACE_FORCE';
ELSIF affiliation in ('MARINES','NAVY') THEN
v_dept_ind := 'NAVY_AND_MARINES';
ELSE v_dept_ind := affiliation;
END IF;

IF is_oconus THEN

SELECT count(*)
INTO v_count
FROM addresses a,
re_oconus_rate_areas o,
jppso_regions j,
gbloc_aors g
WHERE a.us_post_region_cities_id = o.us_post_region_cities_id
and o.id = g.oconus_rate_area_id
and j.id = g.jppso_regions_id
and a.id = address_id;

IF v_count > 1 THEN

--check for gbloc by bos
SELECT count(*)
INTO v_bos_count
FROM addresses a,
re_oconus_rate_areas o,
jppso_regions j,
gbloc_aors g
WHERE a.us_post_region_cities_id = o.us_post_region_cities_id
and o.id = g.oconus_rate_area_id
and j.id = g.jppso_regions_id
and a.id = address_id
and g.department_indicator = v_dept_ind;

IF v_bos_count = 1 THEN

SELECT j.code
INTO gbloc
FROM addresses a,
re_oconus_rate_areas o,
jppso_regions j,
gbloc_aors g
WHERE a.us_post_region_cities_id = o.us_post_region_cities_id
and o.id = g.oconus_rate_area_id
and j.id = g.jppso_regions_id
and a.id = address_id
and g.department_indicator = v_dept_ind;

ELSE

SELECT j.code
INTO gbloc
FROM addresses a,
re_oconus_rate_areas o,
jppso_regions j,
gbloc_aors g
WHERE a.us_post_region_cities_id = o.us_post_region_cities_id
and o.id = g.oconus_rate_area_id
and j.id = g.jppso_regions_id
and a.id = address_id
and g.department_indicator IS NULL;

END IF;

ELSE

SELECT j.code
INTO gbloc
FROM addresses a,
re_oconus_rate_areas o,
jppso_regions j,
gbloc_aors g
WHERE a.us_post_region_cities_id = o.us_post_region_cities_id
and o.id = g.oconus_rate_area_id
and j.id = g.jppso_regions_id
and a.id = address_id;

END IF;

ELSE --is conus

SELECT j.gbloc
INTO gbloc
FROM addresses a,
v_locations o,
postal_code_to_gblocs j
WHERE a.us_post_region_cities_id = o.uprc_id
and o.uspr_zip_id = j.postal_code
and a.id = address_id;

END IF;

IF gbloc IS NULL THEN
RAISE EXCEPTION 'GBLOC not found for address ID % for affiliation %', address_id, affiiation;
END IF;
END;
$$ LANGUAGE plpgsql;
4 changes: 3 additions & 1 deletion pkg/handlers/ghcapi/internal/payloads/model_to_payload.go
Original file line number Diff line number Diff line change
Expand Up @@ -2626,9 +2626,11 @@ func SearchMoves(appCtx appcontext.AppContext, moves models.Moves) *ghcmessages.

// populates the destination postal code of the move
var destinationPostalCode string
destinationPostalCode, err = move.GetDestinationPostalCode(appCtx.DB())
destinationAddress, err := move.GetDestinationAddress(appCtx.DB())
if err != nil {
destinationPostalCode = ""
} else {
destinationPostalCode = destinationAddress.PostalCode
}

searchMoves[i] = &ghcmessages.SearchMove{
Expand Down
14 changes: 7 additions & 7 deletions pkg/handlers/ghcapi/move_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -597,17 +597,17 @@ func (suite *HandlerSuite) TestSearchMovesHandler() {
// Validate outgoing payload without shipment
suite.NoError(payload.Validate(strfmt.Default))

var moveDestinationPostalCode string
var moveDestinationAddress *models.Address
var moveDestinationGBLOC string
var err error

// Get destination postal code and GBLOC based on business logic
moveDestinationPostalCode, err = move.GetDestinationPostalCode(suite.DB())
moveDestinationAddress, err = move.GetDestinationAddress(suite.DB())
suite.NoError(err)
moveDestinationGBLOC, err = move.GetDestinationGBLOC(suite.DB())
suite.NoError(err)

suite.Equal(moveDestinationPostalCode, "62225")
suite.Equal(moveDestinationAddress.PostalCode, "62225")
suite.Equal(ghcmessages.GBLOC(moveDestinationGBLOC), ghcmessages.GBLOC("AGFM"))

// Set Mock Search settings for move with MTO Shipment
Expand Down Expand Up @@ -639,12 +639,12 @@ func (suite *HandlerSuite) TestSearchMovesHandler() {
suite.NoError(payload.Validate(strfmt.Default))

// Get destination postal code and GBLOC based on business logic
moveDestinationPostalCode, err = moveWithShipment.GetDestinationPostalCode(suite.DB())
moveDestinationAddress, err = moveWithShipment.GetDestinationAddress(suite.DB())
suite.NoError(err)
moveDestinationGBLOC, err = moveWithShipment.GetDestinationGBLOC(suite.DB())
suite.NoError(err)

suite.Equal(moveDestinationPostalCode, "90210")
suite.Equal(moveDestinationAddress.PostalCode, "90210")
suite.Equal(ghcmessages.GBLOC(moveDestinationGBLOC), ghcmessages.GBLOC("KKFA"))

// Set Mock Search settings for move with PPM Shipment
Expand Down Expand Up @@ -676,12 +676,12 @@ func (suite *HandlerSuite) TestSearchMovesHandler() {
suite.NoError(payload.Validate(strfmt.Default))

// Get destination postal code and GBLOC based on business logic
moveDestinationPostalCode, err = moveWithShipmentPPM.GetDestinationPostalCode(suite.DB())
moveDestinationAddress, err = moveWithShipmentPPM.GetDestinationAddress(suite.DB())
suite.NoError(err)
moveDestinationGBLOC, err = moveWithShipmentPPM.GetDestinationGBLOC(suite.DB())
suite.NoError(err)

suite.Equal(moveDestinationPostalCode, payload.SearchMoves[0].DestinationPostalCode)
suite.Equal(moveDestinationAddress.PostalCode, payload.SearchMoves[0].DestinationPostalCode)
suite.Equal(ghcmessages.GBLOC(moveDestinationGBLOC), payload.SearchMoves[0].DestinationGBLOC)
})
}
Expand Down
53 changes: 39 additions & 14 deletions pkg/handlers/ghcapi/orders.go
Original file line number Diff line number Diff line change
Expand Up @@ -219,21 +219,46 @@ func (h CreateOrderHandler) Handle(params orderop.CreateOrderParams) middleware.
return orderop.NewCreateOrderUnprocessableEntity(), err
}

destinationGBLOC, err := models.FetchGBLOCForPostalCode(appCtx.DB(), newDutyLocation.Address.PostalCode)
if err != nil {
err = apperror.NewBadDataError("New duty location GBLOC cannot be verified")
appCtx.Logger().Error(err.Error())
return orderop.NewCreateOrderUnprocessableEntity(), err
var newDutyLocationGBLOC *string
if *newDutyLocation.Address.IsOconus {
newDutyLocationGBLOCOconus, err := models.FetchAddressGbloc(appCtx.DB(), newDutyLocation.Address, serviceMember)
if err != nil {
return nil, apperror.NewNotFoundError(newDutyLocation.ID, "while looking for New Duty Location Oconus GBLOC")
}
newDutyLocationGBLOC = newDutyLocationGBLOCOconus
} else {
newDutyLocationGBLOCConus, err := models.FetchGBLOCForPostalCode(appCtx.DB(), newDutyLocation.Address.PostalCode)
if err != nil {
switch err {
case sql.ErrNoRows:
return nil, apperror.NewNotFoundError(newDutyLocation.ID, "while looking for New Duty Location PostalCodeToGBLOC")
default:
err = apperror.NewBadDataError("New duty location GBLOC cannot be verified")
appCtx.Logger().Error(err.Error())
return orderop.NewCreateOrderUnprocessableEntity(), err
}
}
newDutyLocationGBLOC = &newDutyLocationGBLOCConus.GBLOC
}

originDutyLocationGBLOC, err := models.FetchGBLOCForPostalCode(appCtx.DB(), originDutyLocation.Address.PostalCode)
if err != nil {
switch err {
case sql.ErrNoRows:
return nil, apperror.NewNotFoundError(originDutyLocation.ID, "while looking for Duty Location PostalCodeToGBLOC")
default:
return nil, apperror.NewQueryError("PostalCodeToGBLOC", err, "")
var originDutyLocationGBLOC *string
if *originDutyLocation.Address.IsOconus {
originDutyLocationGBLOCOconus, err := models.FetchAddressGbloc(appCtx.DB(), originDutyLocation.Address, serviceMember)
if err != nil {
return nil, apperror.NewNotFoundError(originDutyLocation.ID, "while looking for Origin Duty Location Oconus GBLOC")
}
originDutyLocationGBLOC = originDutyLocationGBLOCOconus
} else {
originDutyLocationGBLOCConus, err := models.FetchGBLOCForPostalCode(appCtx.DB(), originDutyLocation.Address.PostalCode)
if err != nil {
switch err {
case sql.ErrNoRows:
return nil, apperror.NewNotFoundError(originDutyLocation.ID, "while looking for Origin Duty Location PostalCodeToGBLOC")
default:
return nil, apperror.NewQueryError("PostalCodeToGBLOC", err, "")
}
}
originDutyLocationGBLOC = &originDutyLocationGBLOCConus.GBLOC
}

grade := (internalmessages.OrderPayGrade)(*payload.Grade)
Expand Down Expand Up @@ -317,9 +342,9 @@ func (h CreateOrderHandler) Handle(params orderop.CreateOrderParams) middleware.
&originDutyLocation,
&grade,
&entitlement,
&originDutyLocationGBLOC.GBLOC,
originDutyLocationGBLOC,
packingAndShippingInstructions,
&destinationGBLOC.GBLOC,
newDutyLocationGBLOC,
)
if err != nil || verrs.HasAny() {
return handlers.ResponseForVErrors(appCtx.Logger(), verrs, err), err
Expand Down
Loading

0 comments on commit 9976287

Please sign in to comment.