From 079aef89c7ca302a20d2f3fe5fd874d4cbf54ea4 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Thu, 21 Nov 2024 21:04:55 +0000 Subject: [PATCH 01/15] initial commit and migration, needs work --- migrations/app/migrations_manifest.txt | 1 + ...cing_stored_proc_for_intl_shipments.up.sql | 141 ++++++++++++++++++ 2 files changed, 142 insertions(+) create mode 100644 migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql diff --git a/migrations/app/migrations_manifest.txt b/migrations/app/migrations_manifest.txt index 8bd2c8a573e..aae1f692ee9 100644 --- a/migrations/app/migrations_manifest.txt +++ b/migrations/app/migrations_manifest.txt @@ -1043,6 +1043,7 @@ 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 +20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql 20241122155416_total_dependents_calculation.up.sql 20241122220314_create_port_and_port_location_test_data.up.sql 20241126222026_add_sort_column_to_re_service_items.up.sql diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql new file mode 100644 index 00000000000..c197e7344cc --- /dev/null +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -0,0 +1,141 @@ +ALTER TABLE addresses + ADD CONSTRAINT us_post_region_cities_id_fkey + FOREIGN KEY (us_post_region_cities_id) REFERENCES us_post_region_cities (id); + +DROP FUNCTION IF EXISTS calculate_escalated_price(uuid, uuid, uuid, uuid); + +-- function to get the rate area id +CREATE OR REPLACE FUNCTION get_rate_area_id( + address_id UUID, + service_item_id UUID, + OUT o_rate_area_id UUID +) +RETURNS UUID AS $$ +BEGIN + SELECT ro.rate_area_id + INTO o_rate_area_id + FROM addresses a + JOIN re_oconus_rate_areas ro + ON a.us_post_region_cities_id = ro.us_post_region_cities_id + WHERE a.id = address_id; + + IF o_rate_area_id IS NULL THEN + RAISE EXCEPTION 'Rate area not found for address % for service item id %', address_id, service_item_id; + END IF; +END; +$$ LANGUAGE plpgsql; + +-- function to get the contract id based off of a specific date that falls between start/end +CREATE OR REPLACE FUNCTION get_contract_id( + requested_pickup_date DATE, + OUT o_contract_id UUID +) +RETURNS UUID AS $$ +BEGIN + -- Get the contract_id from the re_contract_years table + SELECT rcy.contract_id + INTO o_contract_id + FROM re_contract_years rcy + WHERE requested_pickup_date BETWEEN rcy.start_date AND rcy.end_date; + + -- Check if contract_id is found, else raise an exception + IF o_contract_id IS NULL THEN + RAISE EXCEPTION 'Contract not found for requested pickup date %', requested_pickup_date; + END IF; +END; +$$ LANGUAGE plpgsql; + + + +CREATE OR REPLACE FUNCTION calculate_escalated_price( + o_rate_area_id UUID, + d_rate_area_id UUID, + re_service_id UUID, + c_id UUID +) RETURNS NUMERIC AS $$ +DECLARE + per_unit_cents NUMERIC; + escalation_factor NUMERIC; + escalated_price NUMERIC; +BEGIN + SELECT rip.per_unit_cents + INTO per_unit_cents + FROM re_intl_prices rip + WHERE rip.origin_rate_area_id = o_rate_area_id + AND rip.destination_rate_area_id = d_rate_area_id + AND rip.service_id = re_service_id + AND rip.contract_id = c_id; + + -- IF per_unit_cents IS NULL THEN + -- RAISE EXCEPTION 'No matching price found for the given parameters'; + -- END IF; + + SELECT rcy.escalation + INTO escalation_factor + FROM re_contract_years rcy + WHERE rcy.contract_id = c_id; + + IF escalation_factor IS NULL THEN + RAISE EXCEPTION 'Escalation factor not found for contract_id %', contract_id; + END IF; + + -- Calculate the escalated price + escalated_price := ROUND(per_unit_cents * escalation_factor::NUMERIC / 100, 2); + + RETURN escalated_price; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE PROCEDURE update_service_item_pricing(shipment_id UUID) AS +' +DECLARE + shipment RECORD; + service_item RECORD; + escalated_price NUMERIC; + estimated_price NUMERIC; + o_rate_area_id UUID; + d_rate_area_id UUID; + contract_id UUID; +BEGIN + SELECT ms.id, ms.pickup_address_id, ms.destination_address_id, ms.requested_pickup_date, ms.prime_estimated_weight + INTO shipment + FROM mto_shipments ms + WHERE ms.id = shipment_id; + + IF shipment IS NULL THEN + RAISE EXCEPTION ''Shipment with ID % not found'', shipment_id; + END IF; + + -- Loop through service items in the shipment and update pricing + FOR service_item IN + SELECT si.id, si.re_service_id + FROM mto_service_items si + WHERE si.mto_shipment_id = shipment_id + LOOP + -- Get origin and destination rate areas + o_rate_area_id := get_rate_area_id(shipment.pickup_address_id, service_item.re_service_id); + d_rate_area_id := get_rate_area_id(shipment.destination_address_id, service_item.re_service_id); + contract_id := get_contract_id(shipment.requested_pickup_date); + + -- Calculate the escalated price + escalated_price := calculate_escalated_price( + o_rate_area_id, + d_rate_area_id, + service_item.re_service_id, + contract_id + ); + + -- Calculate estimated and actual prices + IF shipment.prime_estimated_weight IS NOT NULL THEN + estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + END IF; + + -- Update the pricing_estimate in mto_service_items + UPDATE mto_service_items + SET pricing_estimate = estimated_price + WHERE id = service_item.id; + END LOOP; +END; +' +LANGUAGE plpgsql; From addae778c5212643e1d9950f6cd3cda312503bba Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Mon, 25 Nov 2024 17:20:00 +0000 Subject: [PATCH 02/15] adding additional functions and case checks --- ...cing_stored_proc_for_intl_shipments.up.sql | 159 +++++++++++++++--- 1 file changed, 131 insertions(+), 28 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index c197e7344cc..c25c83d8e03 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -25,20 +25,20 @@ BEGIN END; $$ LANGUAGE plpgsql; --- function to get the contract id based off of a specific date that falls between start/end +-- function to get the contract id based off of a specific date that falls between start/end dates CREATE OR REPLACE FUNCTION get_contract_id( requested_pickup_date DATE, OUT o_contract_id UUID ) RETURNS UUID AS $$ BEGIN - -- Get the contract_id from the re_contract_years table + -- get the contract_id from the re_contract_years table SELECT rcy.contract_id INTO o_contract_id FROM re_contract_years rcy WHERE requested_pickup_date BETWEEN rcy.start_date AND rcy.end_date; - -- Check if contract_id is found, else raise an exception + -- check if contract_id is found, else raise an exception IF o_contract_id IS NULL THEN RAISE EXCEPTION 'Contract not found for requested pickup date %', requested_pickup_date; END IF; @@ -46,7 +46,11 @@ END; $$ LANGUAGE plpgsql; - +-- function to calculate the escalated price, takes in: +-- origin rate area +-- dest rate area +-- re_services id +-- contract id CREATE OR REPLACE FUNCTION calculate_escalated_price( o_rate_area_id UUID, d_rate_area_id UUID, @@ -58,13 +62,13 @@ DECLARE escalation_factor NUMERIC; escalated_price NUMERIC; BEGIN - SELECT rip.per_unit_cents + SELECT intl_prices.per_unit_cents INTO per_unit_cents - FROM re_intl_prices rip - WHERE rip.origin_rate_area_id = o_rate_area_id - AND rip.destination_rate_area_id = d_rate_area_id - AND rip.service_id = re_service_id - AND rip.contract_id = c_id; + FROM re_intl_prices intl_prices + WHERE intl_prices.origin_rate_area_id = o_rate_area_id + AND intl_prices.destination_rate_area_id = d_rate_area_id + AND intl_prices.service_id = re_service_id + AND intl_prices.contract_id = c_id; -- IF per_unit_cents IS NULL THEN -- RAISE EXCEPTION 'No matching price found for the given parameters'; @@ -86,6 +90,81 @@ BEGIN END; $$ LANGUAGE plpgsql; +-- function that handles calculating price for ISLH & UBP service items, takes in: +-- origin rate area +-- dest rate area +-- re_services id +-- contract id +-- prime estimated weight +CREATE OR REPLACE FUNCTION calculate_islh_ubp_price( + o_rate_area_id UUID, + d_rate_area_id UUID, + re_service_id UUID, + c_id UUID, + estimated_weight NUMERIC +) RETURNS NUMERIC AS $$ +DECLARE + per_unit_cents NUMERIC; + escalation_factor NUMERIC; + escalated_price NUMERIC; + estimated_price NUMERIC; +BEGIN + SELECT rip.per_unit_cents + INTO per_unit_cents + FROM re_intl_prices rip + WHERE rip.origin_rate_area_id = o_rate_area_id + AND rip.destination_rate_area_id = d_rate_area_id + AND rip.service_id = re_service_id + AND rip.contract_id = c_id; + + SELECT rcy.escalation + INTO escalation_factor + FROM re_contract_years rcy + WHERE rcy.contract_id = c_id; + + escalated_price := ROUND(per_unit_cents * escalation_factor / 100, 2); + estimated_price := ROUND(escalated_price * (estimated_weight / 100), 2); + + RETURN estimated_price; +END; +$$ LANGUAGE plpgsql; + +-- function that handles calculating price for IHPK & IUBPK service items, takes in: +-- origin rate area +-- re_services id +-- contract id +-- prime estimated weight +CREATE OR REPLACE FUNCTION calculate_ihpk_iubpk_price( + o_rate_area_id UUID, + re_service_id UUID, + c_id UUID, + estimated_weight NUMERIC +) RETURNS NUMERIC AS $$ +DECLARE + per_unit_cents NUMERIC; + escalation_factor NUMERIC; + escalated_price NUMERIC; + estimated_price NUMERIC; +BEGIN + SELECT rip.per_unit_cents + INTO per_unit_cents + FROM re_intl_prices rip + WHERE rip.origin_rate_area_id = o_rate_area_id + AND rip.service_id = re_service_id + AND rip.contract_id = c_id; + + SELECT rcy.escalation + INTO escalation_factor + FROM re_contract_years rcy + WHERE rcy.contract_id = c_id; + + escalated_price := ROUND(per_unit_cents * escalation_factor / 100, 2); + estimated_price := ROUND(escalated_price * (estimated_weight / 100), 2); + + RETURN estimated_price; +END; +$$ LANGUAGE plpgsql; + CREATE OR REPLACE PROCEDURE update_service_item_pricing(shipment_id UUID) AS ' @@ -97,6 +176,7 @@ DECLARE o_rate_area_id UUID; d_rate_area_id UUID; contract_id UUID; + service_code TEXT; BEGIN SELECT ms.id, ms.pickup_address_id, ms.destination_address_id, ms.requested_pickup_date, ms.prime_estimated_weight INTO shipment @@ -107,29 +187,52 @@ BEGIN RAISE EXCEPTION ''Shipment with ID % not found'', shipment_id; END IF; - -- Loop through service items in the shipment and update pricing + -- loop through service items in the shipment FOR service_item IN SELECT si.id, si.re_service_id FROM mto_service_items si WHERE si.mto_shipment_id = shipment_id LOOP - -- Get origin and destination rate areas - o_rate_area_id := get_rate_area_id(shipment.pickup_address_id, service_item.re_service_id); - d_rate_area_id := get_rate_area_id(shipment.destination_address_id, service_item.re_service_id); - contract_id := get_contract_id(shipment.requested_pickup_date); - - -- Calculate the escalated price - escalated_price := calculate_escalated_price( - o_rate_area_id, - d_rate_area_id, - service_item.re_service_id, - contract_id - ); - - -- Calculate estimated and actual prices - IF shipment.prime_estimated_weight IS NOT NULL THEN - estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); - END IF; + -- get the service code for the current service item to determine calculation + SELECT code + INTO service_code + FROM re_services + WHERE id = service_item.re_service_id; + + CASE + WHEN service_code IN (''ISLH'', ''UBP'') THEN + o_rate_area_id := get_rate_area_id(shipment.pickup_address_id, service_item.re_service_id); + d_rate_area_id := get_rate_area_id(shipment.destination_address_id, service_item.re_service_id); + contract_id := get_contract_id(shipment.requested_pickup_date); + escalated_price := calculate_escalated_price(o_rate_area_id, d_rate_area_id, service_item.re_service_id, contract_id); + + IF shipment.prime_estimated_weight IS NOT NULL THEN + estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + END IF; + + WHEN service_code IN (''IHPK'', ''IUBPK'') THEN + -- perform IHPK/IUBPK-specific logic (no destination rate area) + o_rate_area_id := get_rate_area_id(shipment.pickup_address_id, service_item.re_service_id); + contract_id := get_contract_id(shipment.requested_pickup_date); + escalated_price := calculate_escalated_price(o_rate_area_id, NULL, service_item.re_service_id, contract_id); + + IF shipment.prime_estimated_weight IS NOT NULL THEN + estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + END IF; + + WHEN service_code IN (''IHUPK'', ''IUBUPK'') THEN + -- perform IHUPK/IUBUPK-specific logic (no origin rate area) + d_rate_area_id := get_rate_area_id(shipment.destination_address_id, service_item.re_service_id); + contract_id := get_contract_id(shipment.requested_pickup_date); + escalated_price := calculate_escalated_price(NULL, d_rate_area_id, service_item.re_service_id, contract_id); + + IF shipment.prime_estimated_weight IS NOT NULL THEN + estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + END IF; + + WHEN service_code IN (''POEFSC'', ''PODFSC'') THEN + estimated_price := 0; -- placeholder + END CASE; -- Update the pricing_estimate in mto_service_items UPDATE mto_service_items From 72f892c0e04225f3d0e4f03c57214220c9ad0af7 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Tue, 26 Nov 2024 22:50:28 +0000 Subject: [PATCH 03/15] improving modularity with additional functions, adding in POE/PODFSC logic --- ...cing_stored_proc_for_intl_shipments.up.sql | 206 ++++++++++++++++-- 1 file changed, 186 insertions(+), 20 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index c25c83d8e03..9c7f72d0942 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -2,8 +2,6 @@ ALTER TABLE addresses ADD CONSTRAINT us_post_region_cities_id_fkey FOREIGN KEY (us_post_region_cities_id) REFERENCES us_post_region_cities (id); -DROP FUNCTION IF EXISTS calculate_escalated_price(uuid, uuid, uuid, uuid); - -- function to get the rate area id CREATE OR REPLACE FUNCTION get_rate_area_id( address_id UUID, @@ -55,24 +53,37 @@ CREATE OR REPLACE FUNCTION calculate_escalated_price( o_rate_area_id UUID, d_rate_area_id UUID, re_service_id UUID, - c_id UUID + c_id UUID, + service_code TEXT ) RETURNS NUMERIC AS $$ DECLARE per_unit_cents NUMERIC; escalation_factor NUMERIC; escalated_price NUMERIC; BEGIN - SELECT intl_prices.per_unit_cents - INTO per_unit_cents - FROM re_intl_prices intl_prices - WHERE intl_prices.origin_rate_area_id = o_rate_area_id - AND intl_prices.destination_rate_area_id = d_rate_area_id - AND intl_prices.service_id = re_service_id - AND intl_prices.contract_id = c_id; + -- we need to query the appropriate table based on the service code + IF service_code IN ('ISLH', 'UBP') THEN + SELECT rip.per_unit_cents + INTO per_unit_cents + FROM re_intl_prices rip + WHERE (rip.origin_rate_area_id = o_rate_area_id OR o_rate_area_id IS NULL) + AND (rip.destination_rate_area_id = d_rate_area_id OR d_rate_area_id IS NULL) + AND rip.service_id = re_service_id + AND rip.contract_id = c_id; + ELSE + SELECT riop.per_unit_cents + INTO per_unit_cents + FROM re_intl_other_prices riop + WHERE (riop.rate_area_id = o_rate_area_id OR riop.rate_area_id = d_rate_area_id OR + (o_rate_area_id IS NULL AND d_rate_area_id IS NULL)) + AND riop.service_id = re_service_id + AND riop.contract_id = c_id; + + END IF; - -- IF per_unit_cents IS NULL THEN - -- RAISE EXCEPTION 'No matching price found for the given parameters'; - -- END IF; + IF per_unit_cents IS NULL THEN + RAISE EXCEPTION 'No per unit cents found for service item id: %, origin rate area: %, dest rate area: %, and contract_id: %', re_service_id, o_rate_area_id, d_rate_area_id, c_id; + END IF; SELECT rcy.escalation INTO escalation_factor @@ -80,16 +91,121 @@ BEGIN WHERE rcy.contract_id = c_id; IF escalation_factor IS NULL THEN - RAISE EXCEPTION 'Escalation factor not found for contract_id %', contract_id; + RAISE EXCEPTION 'Escalation factor not found for contract_id %', c_id; END IF; - -- Calculate the escalated price + -- calculate the escalated price escalated_price := ROUND(per_unit_cents * escalation_factor::NUMERIC / 100, 2); RETURN escalated_price; END; $$ LANGUAGE plpgsql; + +-- get ZIP code by passing in a shipment ID and the address type +-- used for PODFSC & POEFSC service item types +CREATE OR REPLACE FUNCTION get_zip_code(shipment_id uuid, address_type VARCHAR) +RETURNS INT AS $$ + DECLARE zip_code VARCHAR; + BEGIN + + IF address_type = 'pickup' THEN + SELECT vl.uspr_zip_id + INTO zip_code + FROM mto_shipments ms + JOIN addresses a ON a.id = ms.pickup_address_id + JOIN v_locations vl ON vl.uprc_id = a.us_post_region_cities_id + WHERE ms.id = shipment_id; + ELSIF address_type = 'destination' THEN + SELECT vl.uspr_zip_id + INTO zip_code + FROM mto_shipments ms + JOIN addresses a ON a.id = ms.destination_address_id + JOIN v_locations vl ON vl.uprc_id = a.us_post_region_cities_id + WHERE ms.id = shipment_id; + ELSIF address_type = 'poe' THEN + SELECT vl.uspr_zip_id + INTO zip_code + FROM mto_service_items si + JOIN port_locations pl ON pl.id = si.poe_location_id + JOIN v_locations vl ON vl.uprc_id = pl.us_post_region_cities_id + WHERE si.mto_shipment_id = shipment_id; + ELSIF address_type = 'pod' THEN + SELECT vl.uspr_zip_id + INTO zip_code + FROM mto_service_items si + JOIN port_locations pl ON pl.id = si.pod_location_id + JOIN v_locations vl ON vl.uprc_id = pl.us_post_region_cities_id + WHERE si.mto_shipment_id = shipment_id; + END IF; + + RETURN zip_code; +END; +$$ LANGUAGE plpgsql; + +-- getting the distance between two ZIPs +CREATE OR REPLACE FUNCTION get_distance(o_zip_code VARCHAR, d_zip_code VARCHAR) +RETURNS INT AS $$ + DECLARE dist INT; + BEGIN + + SELECT zd.distance_miles + INTO dist + FROM zip3_distances zd + WHERE (zd.from_zip3 = o_zip_code AND zd.to_zip3 = d_zip_code) + OR (zd.from_zip3 = d_zip_code AND zd.to_zip3 = o_zip_code); + + -- if no distance found, return 0 (or you could handle calling DTOD here) + IF dist IS NULL THEN + RETURN 0; + END IF; + + RETURN dist; +END; +$$ LANGUAGE plpgsql; + + +-- querying the re_fsc_multiplier table and getting the multiplier value +CREATE OR REPLACE FUNCTION get_fsc_multiplier(weight INT, rate_area_id uuid) +RETURNS DECIMAL AS $$ + DECLARE m NUMERIC; + BEGIN + + SELECT multiplier + INTO m + FROM re_fsc_multipliers + WHERE weight >= low_weight AND weight <= high_weight + AND rate_area_id = rate_area_id; + + RETURN m; +END; +$$ LANGUAGE plpgsql; + + +-- getting the fuel price from the ghc_diesel_fuel_prices table +CREATE OR REPLACE FUNCTION get_fuel_price(requested_pickup_date DATE) +RETURNS DECIMAL AS $$ + DECLARE fuel_price DECIMAL; + BEGIN + + SELECT fuel_price_in_millicents / 100000 + INTO fuel_price + FROM ghc_diesel_fuel_prices + WHERE requested_pickup_date BETWEEN effective_date AND end_date; + + RETURN fuel_price; +END; +$$ LANGUAGE plpgsql; + + +-- calculating difference from fuel price from base price +CREATE OR REPLACE FUNCTION calculate_price_difference(fuel_price DECIMAL) +RETURNS DECIMAL AS $$ +BEGIN + RETURN (fuel_price - 2.50); +END; +$$ LANGUAGE plpgsql; + -- function that handles calculating price for ISLH & UBP service items, takes in: -- origin rate area -- dest rate area @@ -117,11 +233,19 @@ BEGIN AND rip.service_id = re_service_id AND rip.contract_id = c_id; + IF per_unit_cents IS NULL THEN + RAISE EXCEPTION 'No per unit cents found for service item id: %, origin rate area: %, dest rate area: %, and contract_id: %', re_service_id, o_rate_area_id, d_rate_area_id, c_id; + END IF; + SELECT rcy.escalation INTO escalation_factor FROM re_contract_years rcy WHERE rcy.contract_id = c_id; + IF escalation_factor IS NULL THEN + RAISE EXCEPTION 'Escalation factor not found for contract_id %', contract_id; + END IF; + escalated_price := ROUND(per_unit_cents * escalation_factor / 100, 2); estimated_price := ROUND(escalated_price * (estimated_weight / 100), 2); @@ -153,11 +277,19 @@ BEGIN AND rip.service_id = re_service_id AND rip.contract_id = c_id; + IF per_unit_cents IS NULL THEN + RAISE EXCEPTION 'No per unit cents found for service item id: %, origin rate area: %, and contract_id: %', re_service_id, o_rate_area_id, c_id; + END IF; + SELECT rcy.escalation INTO escalation_factor FROM re_contract_years rcy WHERE rcy.contract_id = c_id; + IF escalation_factor IS NULL THEN + RAISE EXCEPTION 'Escalation factor not found for contract_id %', contract_id; + END IF; + escalated_price := ROUND(per_unit_cents * escalation_factor / 100, 2); estimated_price := ROUND(escalated_price * (estimated_weight / 100), 2); @@ -177,6 +309,12 @@ DECLARE d_rate_area_id UUID; contract_id UUID; service_code TEXT; + o_zip_code TEXT; + d_zip_code TEXT; + distance NUMERIC; + estimated_fsc_multiplier NUMERIC; + fuel_price NUMERIC; + price_difference NUMERIC; BEGIN SELECT ms.id, ms.pickup_address_id, ms.destination_address_id, ms.requested_pickup_date, ms.prime_estimated_weight INTO shipment @@ -187,6 +325,11 @@ BEGIN RAISE EXCEPTION ''Shipment with ID % not found'', shipment_id; END IF; + -- exit the proc if prime_estimated_weight is NULL + IF shipment.prime_estimated_weight IS NULL THEN + RETURN; + END IF; + -- loop through service items in the shipment FOR service_item IN SELECT si.id, si.re_service_id @@ -204,7 +347,7 @@ BEGIN o_rate_area_id := get_rate_area_id(shipment.pickup_address_id, service_item.re_service_id); d_rate_area_id := get_rate_area_id(shipment.destination_address_id, service_item.re_service_id); contract_id := get_contract_id(shipment.requested_pickup_date); - escalated_price := calculate_escalated_price(o_rate_area_id, d_rate_area_id, service_item.re_service_id, contract_id); + escalated_price := calculate_escalated_price(o_rate_area_id, d_rate_area_id, service_item.re_service_id, contract_id, service_code); IF shipment.prime_estimated_weight IS NOT NULL THEN estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); @@ -214,7 +357,7 @@ BEGIN -- perform IHPK/IUBPK-specific logic (no destination rate area) o_rate_area_id := get_rate_area_id(shipment.pickup_address_id, service_item.re_service_id); contract_id := get_contract_id(shipment.requested_pickup_date); - escalated_price := calculate_escalated_price(o_rate_area_id, NULL, service_item.re_service_id, contract_id); + escalated_price := calculate_escalated_price(o_rate_area_id, NULL, service_item.re_service_id, contract_id, service_code); IF shipment.prime_estimated_weight IS NOT NULL THEN estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); @@ -224,17 +367,40 @@ BEGIN -- perform IHUPK/IUBUPK-specific logic (no origin rate area) d_rate_area_id := get_rate_area_id(shipment.destination_address_id, service_item.re_service_id); contract_id := get_contract_id(shipment.requested_pickup_date); - escalated_price := calculate_escalated_price(NULL, d_rate_area_id, service_item.re_service_id, contract_id); + escalated_price := calculate_escalated_price(NULL, d_rate_area_id, service_item.re_service_id, contract_id, service_code); IF shipment.prime_estimated_weight IS NOT NULL THEN estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); END IF; WHEN service_code IN (''POEFSC'', ''PODFSC'') THEN - estimated_price := 0; -- placeholder + IF service_code = ''POEFSC'' THEN + o_zip_code := get_zip_code(shipment.id, ''pickup''); + d_zip_code := get_zip_code(shipment.id, ''poe''); + END IF; + + IF service_code = ''PODFSC'' THEN + o_zip_code := get_zip_code(shipment.id, ''destination''); + d_zip_code := get_zip_code(shipment.id, ''pod''); + END IF; + + -- getting distance between the two ZIPs + distance := get_distance(o_zip_code, d_zip_code); + + -- getting FSC multiplier from re_fsc_multipliers + estimated_fsc_multiplier := get_fsc_multiplier(shipment.prime_estimated_weight, o_rate_area_id); + + fuel_price := get_fuel_price(shipment.requested_pickup_date); + + price_difference := calculate_price_difference(fuel_price); + + -- calculate estimated price + IF estimated_fsc_multiplier IS NOT NULL AND distance IS NOT NULL THEN + estimated_price := ROUND(distance * estimated_fsc_multiplier * price_difference, 2); + END IF; END CASE; - -- Update the pricing_estimate in mto_service_items + -- update the pricing_estimate value in mto_service_items UPDATE mto_service_items SET pricing_estimate = estimated_price WHERE id = service_item.id; From 60415bbd3829345dc8c787d022f3f2760a2fbb59 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Wed, 27 Nov 2024 15:56:18 +0000 Subject: [PATCH 04/15] getting closer, need to refine POD/POEFSC calculations, dont seem quite right --- ...cing_stored_proc_for_intl_shipments.up.sql | 64 +++++++++++++++---- 1 file changed, 51 insertions(+), 13 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index 9c7f72d0942..2c6ef8e9626 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -139,6 +139,10 @@ RETURNS INT AS $$ WHERE si.mto_shipment_id = shipment_id; END IF; + IF zip_code IS NULL THEN + RAISE EXCEPTION 'zip_code not found for shipment id: % and address type of: %', shipment_id, address_type; + END IF; + RETURN zip_code; END; $$ LANGUAGE plpgsql; @@ -146,16 +150,24 @@ $$ LANGUAGE plpgsql; -- getting the distance between two ZIPs CREATE OR REPLACE FUNCTION get_distance(o_zip_code VARCHAR, d_zip_code VARCHAR) RETURNS INT AS $$ - DECLARE dist INT; - BEGIN - +DECLARE + dist INT; +BEGIN + -- get the last 3 characters from both zip codes SELECT zd.distance_miles INTO dist FROM zip3_distances zd - WHERE (zd.from_zip3 = o_zip_code AND zd.to_zip3 = d_zip_code) - OR (zd.from_zip3 = d_zip_code AND zd.to_zip3 = o_zip_code); + WHERE (zd.from_zip3 = RIGHT(o_zip_code, 3) AND zd.to_zip3 = RIGHT(d_zip_code, 3)) + OR (zd.from_zip3 = RIGHT(d_zip_code, 3) AND zd.to_zip3 = RIGHT(o_zip_code, 3)); - -- if no distance found, return 0 (or you could handle calling DTOD here) + IF dist IS NOT NULL THEN + RAISE NOTICE 'Distance found between o_zip_code % and d_zip_code %: % miles', o_zip_code, d_zip_code, dist; + ELSE + RAISE NOTICE 'No distance found for o_zip_code: % and d_zip_code: %', o_zip_code, d_zip_code; + RETURN 0; + END IF; + + -- If no distance found, return 0 - we will have the backend call DTOD IF dist IS NULL THEN RETURN 0; END IF; @@ -165,8 +177,10 @@ END; $$ LANGUAGE plpgsql; + +DROP FUNCTION get_fsc_multiplier(integer); -- querying the re_fsc_multiplier table and getting the multiplier value -CREATE OR REPLACE FUNCTION get_fsc_multiplier(weight INT, rate_area_id uuid) +CREATE OR REPLACE FUNCTION get_fsc_multiplier(estimated_weight INT) RETURNS DECIMAL AS $$ DECLARE m NUMERIC; BEGIN @@ -174,8 +188,13 @@ RETURNS DECIMAL AS $$ SELECT multiplier INTO m FROM re_fsc_multipliers - WHERE weight >= low_weight AND weight <= high_weight - AND rate_area_id = rate_area_id; + WHERE estimated_weight >= low_weight AND estimated_weight <= high_weight; + + RAISE NOTICE 'Received FSC multiplier for estimated_weight: %', m; + + IF m IS NULL THEN + RAISE EXCEPTION 'multipler not found for weight of %', estimated_weight; + END IF; RETURN m; END; @@ -185,14 +204,30 @@ $$ LANGUAGE plpgsql; -- getting the fuel price from the ghc_diesel_fuel_prices table CREATE OR REPLACE FUNCTION get_fuel_price(requested_pickup_date DATE) RETURNS DECIMAL AS $$ - DECLARE fuel_price DECIMAL; - BEGIN +DECLARE + fuel_price DECIMAL; +BEGIN SELECT fuel_price_in_millicents / 100000 INTO fuel_price FROM ghc_diesel_fuel_prices WHERE requested_pickup_date BETWEEN effective_date AND end_date; + -- if no results, fallback to the most recent fuel price + IF fuel_price IS NULL THEN + SELECT fuel_price_in_millicents / 100000 + INTO fuel_price + FROM ghc_diesel_fuel_prices + ORDER BY publication_date DESC + LIMIT 1; + END IF; + + RAISE NOTICE 'Received fuel price of % for requested_pickup_date: %', fuel_price, requested_pickup_date; + + IF fuel_price IS NULL THEN + RAISE EXCEPTION 'No fuel price found for requested_pickup_date: %', requested_pickup_date; + END IF; + RETURN fuel_price; END; $$ LANGUAGE plpgsql; @@ -202,7 +237,7 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION calculate_price_difference(fuel_price DECIMAL) RETURNS DECIMAL AS $$ BEGIN - RETURN (fuel_price - 2.50); + RETURN ABS(fuel_price - 2.50); END; $$ LANGUAGE plpgsql; @@ -388,15 +423,18 @@ BEGIN distance := get_distance(o_zip_code, d_zip_code); -- getting FSC multiplier from re_fsc_multipliers - estimated_fsc_multiplier := get_fsc_multiplier(shipment.prime_estimated_weight, o_rate_area_id); + estimated_fsc_multiplier := get_fsc_multiplier(shipment.prime_estimated_weight); fuel_price := get_fuel_price(shipment.requested_pickup_date); price_difference := calculate_price_difference(fuel_price); + RAISE NOTICE ''Received estimated price data for service_code: %. o_zip_code: %, d_zip_code: %, distance: %, estimated_fsc_multiplier: %, fuel_price: %, price_difference: %'', service_code, o_zip_code, d_zip_code, distance, estimated_fsc_multiplier, fuel_price, price_difference; + -- calculate estimated price IF estimated_fsc_multiplier IS NOT NULL AND distance IS NOT NULL THEN estimated_price := ROUND(distance * estimated_fsc_multiplier * price_difference, 2); + RAISE NOTICE ''Received estimated price of % for service_code: %.'', estimated_price, service_code; END IF; END CASE; From 81882e650913d47e4f06a60a4bfb62896870c820 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Wed, 27 Nov 2024 17:31:34 +0000 Subject: [PATCH 05/15] removing drop function --- ...eate_estimated_pricing_stored_proc_for_intl_shipments.up.sql | 2 -- 1 file changed, 2 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index 2c6ef8e9626..e41fb22e66c 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -177,8 +177,6 @@ END; $$ LANGUAGE plpgsql; - -DROP FUNCTION get_fsc_multiplier(integer); -- querying the re_fsc_multiplier table and getting the multiplier value CREATE OR REPLACE FUNCTION get_fsc_multiplier(estimated_weight INT) RETURNS DECIMAL AS $$ From 779f2026ae0e61baa7318ad1838a39d4702ae850 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Wed, 27 Nov 2024 18:39:58 +0000 Subject: [PATCH 06/15] updated to return as cents, waiting on clarification for calculating price difference --- ...mated_pricing_stored_proc_for_intl_shipments.up.sql | 10 +++++++--- 1 file changed, 7 insertions(+), 3 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index e41fb22e66c..e9109511743 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -235,6 +235,10 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION calculate_price_difference(fuel_price DECIMAL) RETURNS DECIMAL AS $$ BEGIN + IF fuel_price < 2.50 THEN + RETURN fuel_price; + END IF; + RETURN ABS(fuel_price - 2.50); END; $$ LANGUAGE plpgsql; @@ -429,10 +433,10 @@ BEGIN RAISE NOTICE ''Received estimated price data for service_code: %. o_zip_code: %, d_zip_code: %, distance: %, estimated_fsc_multiplier: %, fuel_price: %, price_difference: %'', service_code, o_zip_code, d_zip_code, distance, estimated_fsc_multiplier, fuel_price, price_difference; - -- calculate estimated price + -- calculate estimated price, return as cents IF estimated_fsc_multiplier IS NOT NULL AND distance IS NOT NULL THEN - estimated_price := ROUND(distance * estimated_fsc_multiplier * price_difference, 2); - RAISE NOTICE ''Received estimated price of % for service_code: %.'', estimated_price, service_code; + estimated_price := ROUND(distance * estimated_fsc_multiplier * price_difference * 100); + RAISE NOTICE ''Received estimated price of % cents for service_code: %.'', estimated_price, service_code; END IF; END CASE; From f5cf57eb87380d0b15f95960aceda6bcdc7d6342 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Fri, 6 Dec 2024 18:40:54 +0000 Subject: [PATCH 07/15] updating functions and data --- .envrc | 2 +- ...cing_stored_proc_for_intl_shipments.up.sql | 67 +++++++++++++------ 2 files changed, 46 insertions(+), 23 deletions(-) diff --git a/.envrc b/.envrc index 3891c5b8d85..02c400ca703 100644 --- a/.envrc +++ b/.envrc @@ -154,7 +154,7 @@ export FEATURE_FLAG_NTS=true export FEATURE_FLAG_NTSR=true export FEATURE_FLAG_BOAT=true export FEATURE_FLAG_MOBILE_HOME=true -export FEATURE_FLAG_UNACCOMPANIED_BAGGAGE=false +export FEATURE_FLAG_UNACCOMPANIED_BAGGAGE=true # Feature flag to allow AK to be entered as a state export FEATURE_FLAG_ENABLE_ALASKA=true diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index e9109511743..2b152bc5347 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -2,23 +2,48 @@ ALTER TABLE addresses ADD CONSTRAINT us_post_region_cities_id_fkey FOREIGN KEY (us_post_region_cities_id) REFERENCES us_post_region_cities (id); --- function to get the rate area id +-- function to get the rate area id for any address CREATE OR REPLACE FUNCTION get_rate_area_id( address_id UUID, service_item_id UUID, OUT o_rate_area_id UUID ) RETURNS UUID AS $$ +DECLARE + is_oconus BOOLEAN; + zip3_value TEXT; BEGIN - SELECT ro.rate_area_id - INTO o_rate_area_id - FROM addresses a - JOIN re_oconus_rate_areas ro - ON a.us_post_region_cities_id = ro.us_post_region_cities_id - WHERE a.id = address_id; + is_oconus := get_is_oconus(address_id); + + IF is_oconus THEN + -- re_oconus_rate_areas if is_oconus is TRUE + SELECT ro.rate_area_id + INTO o_rate_area_id + FROM addresses a + JOIN re_oconus_rate_areas ro + ON a.us_post_region_cities_id = ro.us_post_region_cities_id + WHERE a.id = address_id; + ELSE + -- re_zip3s if is_oconus is FALSE + SELECT rupr.zip3 + INTO zip3_value + FROM addresses a + JOIN us_post_region_cities uprc + ON a.us_post_region_cities_id = uprc.id + JOIN re_us_post_regions rupr + ON uprc.us_post_regions_id = rupr.id + WHERE a.id = address_id; + + -- use the zip3 value to find the rate_area_id in re_zip3s + SELECT rz.rate_area_id + INTO o_rate_area_id + FROM re_zip3s rz + WHERE rz.zip3 = zip3_value; + END IF; + -- Raise an exception if no rate area is found IF o_rate_area_id IS NULL THEN - RAISE EXCEPTION 'Rate area not found for address % for service item id %', address_id, service_item_id; + RAISE EXCEPTION 'Rate area not found for address % for service item ID %', address_id, service_item_id; END IF; END; $$ LANGUAGE plpgsql; @@ -157,8 +182,8 @@ BEGIN SELECT zd.distance_miles INTO dist FROM zip3_distances zd - WHERE (zd.from_zip3 = RIGHT(o_zip_code, 3) AND zd.to_zip3 = RIGHT(d_zip_code, 3)) - OR (zd.from_zip3 = RIGHT(d_zip_code, 3) AND zd.to_zip3 = RIGHT(o_zip_code, 3)); + WHERE (zd.from_zip3 = LEFT(o_zip_code, 3) AND zd.to_zip3 = LEFT(d_zip_code, 3)) + OR (zd.from_zip3 = LEFT(d_zip_code, 3) AND zd.to_zip3 = LEFT(o_zip_code, 3)); IF dist IS NOT NULL THEN RAISE NOTICE 'Distance found between o_zip_code % and d_zip_code %: % miles', o_zip_code, d_zip_code, dist; @@ -206,21 +231,21 @@ DECLARE fuel_price DECIMAL; BEGIN - SELECT fuel_price_in_millicents / 100000 + SELECT ROUND(fuel_price_in_millicents::DECIMAL / 100000, 2) INTO fuel_price FROM ghc_diesel_fuel_prices WHERE requested_pickup_date BETWEEN effective_date AND end_date; -- if no results, fallback to the most recent fuel price IF fuel_price IS NULL THEN - SELECT fuel_price_in_millicents / 100000 + SELECT ROUND(fuel_price_in_millicents::DECIMAL / 100000, 2) INTO fuel_price FROM ghc_diesel_fuel_prices ORDER BY publication_date DESC LIMIT 1; END IF; - RAISE NOTICE 'Received fuel price of % for requested_pickup_date: %', fuel_price, requested_pickup_date; + RAISE NOTICE 'Received fuel price of $% for requested_pickup_date: %', fuel_price, requested_pickup_date; IF fuel_price IS NULL THEN RAISE EXCEPTION 'No fuel price found for requested_pickup_date: %', requested_pickup_date; @@ -231,15 +256,11 @@ END; $$ LANGUAGE plpgsql; --- calculating difference from fuel price from base price +-- calculating difference from fuel price from base price, return in cents CREATE OR REPLACE FUNCTION calculate_price_difference(fuel_price DECIMAL) RETURNS DECIMAL AS $$ BEGIN - IF fuel_price < 2.50 THEN - RETURN fuel_price; - END IF; - - RETURN ABS(fuel_price - 2.50); + RETURN (fuel_price - 2.50) * 100; END; $$ LANGUAGE plpgsql; @@ -351,6 +372,7 @@ DECLARE distance NUMERIC; estimated_fsc_multiplier NUMERIC; fuel_price NUMERIC; + cents_above_baseline NUMERIC; price_difference NUMERIC; BEGIN SELECT ms.id, ms.pickup_address_id, ms.destination_address_id, ms.requested_pickup_date, ms.prime_estimated_weight @@ -431,11 +453,12 @@ BEGIN price_difference := calculate_price_difference(fuel_price); - RAISE NOTICE ''Received estimated price data for service_code: %. o_zip_code: %, d_zip_code: %, distance: %, estimated_fsc_multiplier: %, fuel_price: %, price_difference: %'', service_code, o_zip_code, d_zip_code, distance, estimated_fsc_multiplier, fuel_price, price_difference; - -- calculate estimated price, return as cents IF estimated_fsc_multiplier IS NOT NULL AND distance IS NOT NULL THEN - estimated_price := ROUND(distance * estimated_fsc_multiplier * price_difference * 100); + cents_above_baseline := distance * estimated_fsc_multiplier; + RAISE NOTICE ''Distance: % * FSC Multipler: % = $% cents above baseline of $2.50'', distance, estimated_fsc_multiplier, cents_above_baseline; + RAISE NOTICE ''The fuel price is % cents above the baseline ($% - $2.50 baseline)'', price_difference, fuel_price; + estimated_price := ROUND(cents_above_baseline * price_difference) * 100; RAISE NOTICE ''Received estimated price of % cents for service_code: %.'', estimated_price, service_code; END IF; END CASE; From 8d13bcaff4dabae94bc74b7c1bfc08534be98c78 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Fri, 6 Dec 2024 18:47:38 +0000 Subject: [PATCH 08/15] adding call to shipment Go struct --- pkg/models/mto_shipments.go | 12 ++++++++++++ 1 file changed, 12 insertions(+) diff --git a/pkg/models/mto_shipments.go b/pkg/models/mto_shipments.go index 108c49b49b5..4bb6920a793 100644 --- a/pkg/models/mto_shipments.go +++ b/pkg/models/mto_shipments.go @@ -369,3 +369,15 @@ func CreateApprovedServiceItemsForShipment(db *pop.Connection, shipment *MTOShip return nil } + +// a db stored proc that will handle updating the pricing_estimate columns of basic service items for shipment types: +// iHHG +// iUB +func UpdateEstimatedPricingForShimpentBasicServiceItems(db *pop.Connection, shipment *MTOShipment) error { + err := db.RawQuery("CALL update_service_item_pricing($1)", shipment.ID).Exec() + if err != nil { + return fmt.Errorf("error updating estimated pricing for shipment's service items: %w", err) + } + + return nil +} From 4afb552f5f00425d2e99330ba5befcf114481df7 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Fri, 6 Dec 2024 18:53:10 +0000 Subject: [PATCH 09/15] whoops --- .envrc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.envrc b/.envrc index 02c400ca703..3891c5b8d85 100644 --- a/.envrc +++ b/.envrc @@ -154,7 +154,7 @@ export FEATURE_FLAG_NTS=true export FEATURE_FLAG_NTSR=true export FEATURE_FLAG_BOAT=true export FEATURE_FLAG_MOBILE_HOME=true -export FEATURE_FLAG_UNACCOMPANIED_BAGGAGE=true +export FEATURE_FLAG_UNACCOMPANIED_BAGGAGE=false # Feature flag to allow AK to be entered as a state export FEATURE_FLAG_ENABLE_ALASKA=true From 9855b5af673ed2978319be76fd2b721955a7ceeb Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Fri, 6 Dec 2024 20:05:06 +0000 Subject: [PATCH 10/15] updating comments, converting dollars to cents whoops --- ...cing_stored_proc_for_intl_shipments.up.sql | 22 +++++++++++-------- 1 file changed, 13 insertions(+), 9 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index 2b152bc5347..c978a9cd6ae 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -118,10 +118,11 @@ BEGIN IF escalation_factor IS NULL THEN RAISE EXCEPTION 'Escalation factor not found for contract_id %', c_id; END IF; - - -- calculate the escalated price + -- calculate the escalated price, return in dollars (dividing by 100) escalated_price := ROUND(per_unit_cents * escalation_factor::NUMERIC / 100, 2); + RAISE NOTICE '% escalated price: $% (% * % / 100)', service_code, escalated_price, per_unit_cents, escalation_factor; + RETURN escalated_price; END; $$ LANGUAGE plpgsql; @@ -213,12 +214,12 @@ RETURNS DECIMAL AS $$ FROM re_fsc_multipliers WHERE estimated_weight >= low_weight AND estimated_weight <= high_weight; - RAISE NOTICE 'Received FSC multiplier for estimated_weight: %', m; - IF m IS NULL THEN RAISE EXCEPTION 'multipler not found for weight of %', estimated_weight; END IF; + RAISE NOTICE 'Received FSC multiplier for estimated_weight: %', m; + RETURN m; END; $$ LANGUAGE plpgsql; @@ -245,12 +246,12 @@ BEGIN LIMIT 1; END IF; - RAISE NOTICE 'Received fuel price of $% for requested_pickup_date: %', fuel_price, requested_pickup_date; - IF fuel_price IS NULL THEN RAISE EXCEPTION 'No fuel price found for requested_pickup_date: %', requested_pickup_date; END IF; + RAISE NOTICE 'Received fuel price of $% for requested_pickup_date: %', fuel_price, requested_pickup_date; + RETURN fuel_price; END; $$ LANGUAGE plpgsql; @@ -409,7 +410,8 @@ BEGIN escalated_price := calculate_escalated_price(o_rate_area_id, d_rate_area_id, service_item.re_service_id, contract_id, service_code); IF shipment.prime_estimated_weight IS NOT NULL THEN - estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + estimated_price := ROUND((escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC) * 100, 0); + RAISE NOTICE ''%: Received estimated price of % (% * (% / 100)) cents'', service_code, estimated_price, escalated_price, shipment.prime_estimated_weight; END IF; WHEN service_code IN (''IHPK'', ''IUBPK'') THEN @@ -419,7 +421,8 @@ BEGIN escalated_price := calculate_escalated_price(o_rate_area_id, NULL, service_item.re_service_id, contract_id, service_code); IF shipment.prime_estimated_weight IS NOT NULL THEN - estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + estimated_price := ROUND((escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC) * 100, 0); + RAISE NOTICE ''%: Received estimated price of % (% * (% / 100)) cents'', service_code, estimated_price, escalated_price, shipment.prime_estimated_weight; END IF; WHEN service_code IN (''IHUPK'', ''IUBUPK'') THEN @@ -429,7 +432,8 @@ BEGIN escalated_price := calculate_escalated_price(NULL, d_rate_area_id, service_item.re_service_id, contract_id, service_code); IF shipment.prime_estimated_weight IS NOT NULL THEN - estimated_price := ROUND(escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC, 2); + estimated_price := ROUND((escalated_price * (shipment.prime_estimated_weight / 100)::NUMERIC) * 100, 0); + RAISE NOTICE ''%: Received estimated price of % (% * (% / 100)) cents'', service_code, estimated_price, escalated_price, shipment.prime_estimated_weight; END IF; WHEN service_code IN (''POEFSC'', ''PODFSC'') THEN From 28f612f50f8daef226252c2bc79217b359064829 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Tue, 10 Dec 2024 16:56:17 +0000 Subject: [PATCH 11/15] INT to VARCHAR --- ...eate_estimated_pricing_stored_proc_for_intl_shipments.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index c978a9cd6ae..c838d7580f0 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -131,7 +131,7 @@ $$ LANGUAGE plpgsql; -- get ZIP code by passing in a shipment ID and the address type -- used for PODFSC & POEFSC service item types CREATE OR REPLACE FUNCTION get_zip_code(shipment_id uuid, address_type VARCHAR) -RETURNS INT AS $$ +RETURNS VARCHAR AS $$ DECLARE zip_code VARCHAR; BEGIN From 4ffa67df06d19f8d3947b1f8402c600e4e29af54 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Tue, 10 Dec 2024 16:57:46 +0000 Subject: [PATCH 12/15] fixing variable --- ...eate_estimated_pricing_stored_proc_for_intl_shipments.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index c838d7580f0..7762f0e0d39 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -302,7 +302,7 @@ BEGIN WHERE rcy.contract_id = c_id; IF escalation_factor IS NULL THEN - RAISE EXCEPTION 'Escalation factor not found for contract_id %', contract_id; + RAISE EXCEPTION 'Escalation factor not found for contract_id %', c_id; END IF; escalated_price := ROUND(per_unit_cents * escalation_factor / 100, 2); From c4b753476257819dc78e4569c3947a172a89e7c8 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Tue, 10 Dec 2024 18:53:14 +0000 Subject: [PATCH 13/15] in PEMDAS we trust --- ...eate_estimated_pricing_stored_proc_for_intl_shipments.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index 7762f0e0d39..794a8a5a8f0 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -462,7 +462,7 @@ BEGIN cents_above_baseline := distance * estimated_fsc_multiplier; RAISE NOTICE ''Distance: % * FSC Multipler: % = $% cents above baseline of $2.50'', distance, estimated_fsc_multiplier, cents_above_baseline; RAISE NOTICE ''The fuel price is % cents above the baseline ($% - $2.50 baseline)'', price_difference, fuel_price; - estimated_price := ROUND(cents_above_baseline * price_difference) * 100; + estimated_price := ROUND((cents_above_baseline * price_difference) * 100); RAISE NOTICE ''Received estimated price of % cents for service_code: %.'', estimated_price, service_code; END IF; END CASE; From c09ad7dea3885a05027e0e65d69c04292163f098 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Tue, 10 Dec 2024 19:41:09 +0000 Subject: [PATCH 14/15] spelling --- pkg/models/mto_shipments.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/pkg/models/mto_shipments.go b/pkg/models/mto_shipments.go index 4bb6920a793..da5e021a698 100644 --- a/pkg/models/mto_shipments.go +++ b/pkg/models/mto_shipments.go @@ -373,7 +373,7 @@ func CreateApprovedServiceItemsForShipment(db *pop.Connection, shipment *MTOShip // a db stored proc that will handle updating the pricing_estimate columns of basic service items for shipment types: // iHHG // iUB -func UpdateEstimatedPricingForShimpentBasicServiceItems(db *pop.Connection, shipment *MTOShipment) error { +func UpdateEstimatedPricingForShipmentBasicServiceItems(db *pop.Connection, shipment *MTOShipment) error { err := db.RawQuery("CALL update_service_item_pricing($1)", shipment.ID).Exec() if err != nil { return fmt.Errorf("error updating estimated pricing for shipment's service items: %w", err) From 75e484f5ab98e7ef522c58c545c9fec9b389d0d0 Mon Sep 17 00:00:00 2001 From: Daniel Jordan Date: Tue, 10 Dec 2024 21:07:46 +0000 Subject: [PATCH 15/15] removing FK to survive this day --- ...te_estimated_pricing_stored_proc_for_intl_shipments.up.sql | 4 ---- 1 file changed, 4 deletions(-) diff --git a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql index 794a8a5a8f0..2efc4ee4b90 100644 --- a/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql +++ b/migrations/app/schema/20241121205457_create_estimated_pricing_stored_proc_for_intl_shipments.up.sql @@ -1,7 +1,3 @@ -ALTER TABLE addresses - ADD CONSTRAINT us_post_region_cities_id_fkey - FOREIGN KEY (us_post_region_cities_id) REFERENCES us_post_region_cities (id); - -- function to get the rate area id for any address CREATE OR REPLACE FUNCTION get_rate_area_id( address_id UUID,