Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Int b 21668 stored procs for ordering service items #14230

Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
43 commits
Select commit Hold shift + click to select a range
2dfe342
initial commit, added stored proc for creating service items
danieljordan-caci Nov 12, 2024
1b8b4cb
adding stored proc for accessorials - not finished
danieljordan-caci Nov 13, 2024
65ec8f0
checkin
deandreJones Nov 19, 2024
2b84fb2
Merge branch 'INT-B-21668-stored-procs-for-ordering-service-items' of…
deandreJones Nov 19, 2024
9948d7b
refactored migrations to use single quotes
danieljordan-caci Nov 19, 2024
595c51c
change from json to mto_service_item_type
deandreJones Nov 19, 2024
b4c9c2e
basics
deandreJones Nov 19, 2024
2f7a0a5
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 19, 2024
20a1b8f
add estimated and actual weight
deandreJones Nov 19, 2024
2ad536c
Merge branch 'INT-B-21668-stored-procs-for-ordering-service-items' of…
deandreJones Nov 19, 2024
e3a34c4
too many commas
deandreJones Nov 19, 2024
86fc27f
modifications
deandreJones Nov 19, 2024
6e3556d
ed
deandreJones Nov 19, 2024
b0dd405
missed one
deandreJones Nov 19, 2024
9016fb8
remove test- not worth my headache right now
deandreJones Nov 20, 2024
6c9cabd
approved
deandreJones Nov 20, 2024
7dd067a
approved_at , now(()
deandreJones Nov 20, 2024
4c0fde8
app now
deandreJones Nov 20, 2024
6a5fed6
add sts check- upated from read json to compostie trp
deandreJones Nov 20, 2024
c245ca8
port of....sit postal
deandreJones Nov 20, 2024
460280a
add the dup check
deandreJones Nov 20, 2024
ad4727c
add excption
deandreJones Nov 20, 2024
4b1e0ef
Merge branch 'INT-B-21668-stored-procs-for-ordering-service-items' of…
deandreJones Nov 20, 2024
9c63021
add type check
deandreJones Nov 20, 2024
d081b6f
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 20, 2024
9e1b09f
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 21, 2024
6841660
remove odd dup
deandreJones Nov 21, 2024
d61385a
Merge branch 'INT-B-21668-stored-procs-for-ordering-service-items' of…
deandreJones Nov 21, 2024
779aad3
put that back
deandreJones Nov 21, 2024
06c6bc5
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 21, 2024
5fab721
cleanup - renaming..
deandreJones Nov 21, 2024
72847b6
merges
deandreJones Nov 21, 2024
d637ae5
added test- fix call to proc after renaming
deandreJones Nov 22, 2024
f1da27c
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 22, 2024
d324042
mto_service_item_type
deandreJones Nov 22, 2024
abaab40
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 22, 2024
1a0bd43
cleanup
deandreJones Nov 25, 2024
acf63a4
Merge branch 'INT-B-21668-stored-procs-for-ordering-service-items' of…
deandreJones Nov 25, 2024
8406704
correctiuions
deandreJones Nov 25, 2024
b4f7924
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 25, 2024
3069853
Merge branch 'integrationTesting' into INT-B-21668-stored-procs-for-o…
deandreJones Nov 26, 2024
998be6c
json it is
deandreJones Nov 26, 2024
f0bf7f0
Merge branch 'INT-B-21668-stored-procs-for-ordering-service-items' of…
deandreJones Nov 26, 2024
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions migrations/app/migrations_manifest.txt
Original file line number Diff line number Diff line change
Expand Up @@ -1039,6 +1039,7 @@
20241111203514_add_external_crate_and_remove_icrtsa.up.sql
20241111221400_add_new_order_types.up.sql
20241111223224_change_international_sit_services_to_accessorials.up.sql
20241119151019_stored_procs_for_ordering_service_items.up.sql
20241119163933_set_inactive_NSRA15_oconus_rate_areas.up.sql
20241120221040_change_port_location_fk_to_correct_table.up.sql
20241122155416_total_dependents_calculation.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,363 @@
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";

ALTER TABLE mto_service_items
ALTER COLUMN id SET DEFAULT uuid_generate_v4();


-- creating function to get address is_oconus
CREATE OR REPLACE FUNCTION get_is_oconus(address_id UUID)
RETURNS BOOLEAN AS $$
DECLARE
is_oconus BOOLEAN;
BEGIN
SELECT a.is_oconus
INTO is_oconus
FROM addresses a
WHERE a.id = address_id;

RETURN is_oconus;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'Address with ID % not found', address_id;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION does_service_item_exist(
service_id UUID,
shipment_id UUID
) RETURNS BOOLEAN AS $$
BEGIN
IF EXISTS (
SELECT 1
FROM mto_service_items
WHERE re_service_id = service_id
AND mto_shipment_id = shipment_id
) THEN
RAISE EXCEPTION 'Service item already exists for service_id % and shipment_id %', service_id, shipment_id;
END IF;
RETURN FALSE;
END;
cameroncaci marked this conversation as resolved.
Show resolved Hide resolved
$$ LANGUAGE plpgsql;

-- stored proc that creates auto-approved service items based off of a shipment id
CREATE OR REPLACE PROCEDURE create_approved_service_items_for_shipment(
IN shipment_id UUID
)
AS '
DECLARE
s_status mto_shipment_status;
s_type mto_shipment_type;
m_code market_code_enum;
move_id UUID;
pickup_address_id UUID;
destination_address_id UUID;
is_pickup_oconus BOOLEAN;
is_destination_oconus BOOLEAN;
service_item RECORD;
BEGIN
-- get shipment type, market code, move_id, and address IDs based on shipment_id
SELECT ms.shipment_type, ms.market_code, ms.move_id, ms.pickup_address_id, ms.destination_address_id, ms.status
INTO s_type, m_code, move_id, pickup_address_id, destination_address_id, s_status
FROM mto_shipments ms
WHERE ms.id = shipment_id;

IF s_type IS NULL OR m_code IS NULL THEN
RAISE EXCEPTION ''Shipment with ID % not found or missing required details.'', shipment_id;
END IF;

IF s_status IN (''APPROVED'') THEN
RAISE EXCEPTION ''Shipment with ID % is already in APPROVED status'', shipment_id;
END IF;

-- get the is_oconus values for both pickup and destination addresses - this determines POD/POE creation
is_pickup_oconus := get_is_oconus(pickup_address_id);
is_destination_oconus := get_is_oconus(destination_address_id);

-- determine which service item to create based on shipment direction
-- first create the direction-specific service item (POEFSC or PODFSC)
IF is_pickup_oconus AND NOT is_destination_oconus THEN
-- Shipment is OCONUS to CONUS, create PODFSC item
FOR service_item IN
SELECT rsi.id,
rs.id AS re_service_id,
rs.service_location,
rsi.is_auto_approved
FROM re_service_items rsi
JOIN re_services rs ON rsi.service_id = rs.id
WHERE rsi.shipment_type = s_type
AND rsi.market_code = m_code
AND rs.code = ''PODFSC''
AND rsi.is_auto_approved = true
LOOP
BEGIN
IF NOT does_service_item_exist(service_item.re_service_id, shipment_id) THEN
INSERT INTO mto_service_items (
mto_shipment_id,
move_id,
re_service_id,
service_location,
status,
created_at,
updated_at,
approved_at
)
VALUES (
shipment_id,
move_id,
service_item.re_service_id,
service_item.service_location,
''APPROVED''::service_item_status,
NOW(),
NOW(),
NOW()
danieljordan-caci marked this conversation as resolved.
Show resolved Hide resolved
);
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION ''Error creating PODFSC service item for shipment %: %'', shipment_id, SQLERRM;
END;
END LOOP;
ELSIF NOT is_pickup_oconus AND is_destination_oconus THEN
-- Shipment is CONUS to OCONUS, create POEFSC item
FOR service_item IN
SELECT rsi.id,
rs.id AS re_service_id,
rs.service_location,
rsi.is_auto_approved
FROM re_service_items rsi
JOIN re_services rs ON rsi.service_id = rs.id
WHERE rsi.shipment_type = s_type
AND rsi.market_code = m_code
AND rs.code = ''POEFSC''
AND rsi.is_auto_approved = true
LOOP
BEGIN
IF NOT does_service_item_exist(service_item.re_service_id, shipment_id) THEN
INSERT INTO mto_service_items (
mto_shipment_id,
move_id,
re_service_id,
service_location,
status,
created_at,
updated_at,
approved_at
)
VALUES (
shipment_id,
move_id,
service_item.re_service_id,
service_item.service_location,
''APPROVED''::service_item_status,
NOW(),
NOW(),
NOW()
);
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION ''Error creating POEFSC service item for shipment %: %'', shipment_id, SQLERRM;
END;
END LOOP;
ELSE
RAISE EXCEPTION ''Invalid shipment direction for shipment %: Pickup is %CONUS, Destination is %CONUS.'',
shipment_id, is_pickup_oconus, is_destination_oconus;
END IF;

-- create all other auto-approved service items, filtering out the POEFSC or PODFSC service items
FOR service_item IN
SELECT rsi.id,
rs.id AS re_service_id,
rs.service_location,
rsi.is_auto_approved
FROM re_service_items rsi
JOIN re_services rs ON rsi.service_id = rs.id
WHERE rsi.shipment_type = s_type
AND rsi.market_code = m_code
AND rsi.is_auto_approved = true
AND rs.code NOT IN (''POEFSC'', ''PODFSC'')
LOOP
BEGIN
IF NOT does_service_item_exist(service_item.re_service_id, shipment_id) THEN
INSERT INTO mto_service_items (
mto_shipment_id,
move_id,
re_service_id,
service_location,
status,
created_at,
updated_at,
approved_at
)
VALUES (
shipment_id,
move_id,
service_item.re_service_id,
service_item.service_location,
''APPROVED''::service_item_status,
NOW(),
NOW(),
NOW()
);
End IF;
EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION ''Error creating other service item for shipment %: %'', shipment_id, SQLERRM;
END;
END LOOP;
END;
'
LANGUAGE plpgsql;

DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'mto_service_item_type') THEN
CREATE TYPE mto_service_item_type AS (
id uuid,
move_id uuid,
mto_shipment_id uuid,
re_service_id uuid,
created_at timestamptz,
updated_at timestamptz,
reason text,
pickup_postal_code text,
description text,
status public.service_item_status,
rejection_reason text,
approved_at timestamp,
rejected_at timestamp,
sit_postal_code text,
sit_entry_date date,
sit_departure_date date,
sit_destination_final_address_id uuid,
sit_origin_hhg_original_address_id uuid,
sit_origin_hhg_actual_address_id uuid,
estimated_weight int4,
actual_weight int4,
sit_destination_original_address_id uuid,
sit_customer_contacted date,
sit_requested_delivery date,
requested_approvals_requested_status bool,
customer_expense bool,
customer_expense_reason text,
sit_delivery_miles int4,
pricing_estimate int4,
standalone_crate bool,
locked_price_cents int4,
service_location public.service_location_enum,
poe_location_id uuid,
pod_location_id uuid
);
END IF;
END
$$;


CREATE OR REPLACE PROCEDURE create_accessorial_service_items_for_shipment (
IN shipment_id UUID,
IN service_items mto_service_item_type[]
) AS '
DECLARE
s_type mto_shipment_type;
m_code market_code_enum;
move_id UUID;
service_item RECORD;
item mto_service_item_type;
BEGIN
-- get the shipment type, market code, and move_id based on shipment_id
SELECT ms.shipment_type, ms.market_code, ms.move_id
INTO s_type, m_code, move_id
FROM mto_shipments ms
WHERE ms.id = shipment_id;

IF s_type IS NULL OR m_code IS NULL THEN
RAISE EXCEPTION ''Shipment with ID % not found or missing required details.'', shipment_id;
END IF;

IF s_type <> item.shipment_type THEN
RAISE EXCEPTION ''Shipment type mismatch. Expected %, but got %.'', s_type, item.shipment_type;
END IF;

-- loop through each provided service item object
FOREACH item IN ARRAY service_items
LOOP
FOR service_item IN
SELECT rsi.id,
rs.id AS re_service_id,
rs.service_location,
rsi.is_auto_approved,
rs.code AS service_code
FROM re_service_items rsi
JOIN re_services rs ON rsi.service_id = rs.id
WHERE rsi.shipment_type = s_type
AND rsi.market_code = m_code
AND rs.id = (item.re_service_id)
AND rsi.is_auto_approved = false
LOOP
BEGIN
IF NOT does_service_item_exist(service_item.re_service_id, shipment_id) THEN
INSERT INTO mto_service_items (
mto_shipment_id,
move_id,
re_service_id,
service_location,
status,
created_at,
updated_at,
sit_postal_code,
sit_entry_date,
sit_customer_contacted,
reason,
estimated_weight,
actual_weight,
pickup_postal_code,
description,
sit_destination_original_address_id,
sit_destination_final_address_id,
sit_requested_delivery,
sit_departure_date,
sit_origin_hhg_original_address_id,
sit_origin_hhg_actual_address_id,
customer_expense,
customer_expense_reason,
sit_delivery_miles,
standalone_crate
)
VALUES (
shipment_id,
move_id,
service_item.re_service_id,
service_item.service_location,
''SUBMITTED''::service_item_status,
NOW(),
NOW(),
(item).sit_postal_code,
(item).sit_entry_date,
(item).sit_customer_contacted,
(item).reason,
(item).estimated_weight,
(item).actual_weight,
(item).pickup_postal_code,
(item).description,
(item).sit_destination_original_address_id,
(item).sit_destination_final_address_id,
(item).sit_requested_delivery,
(item).sit_departure_date,
(item).sit_origin_hhg_original_address_id,
(item).sit_origin_hhg_actual_address_id,
(item).customer_expense,
(item).customer_expense_reason,
(item).sit_delivery_miles,
(item).standalone_crate
);
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION ''Error creating accessorial service item with code % for shipment %: %'',
service_item.service_code, shipment_id, SQLERRM;
END;
END LOOP;
END LOOP;
END;
'
LANGUAGE plpgsql;
Loading