From 1b46f4224ec93003bed1833444b992a076a2e7b5 Mon Sep 17 00:00:00 2001 From: jordi fita mas Date: Wed, 20 Mar 2024 18:17:58 +0100 Subject: [PATCH] Compute the subtotal of dogs using their number, not as a boolean I swear i believe sometime before we said that the number of dogs is not important and should be used only as a boolean, but apparently it is wrong: it should be number_dogs * cost_per_pet. --- deploy/draft_payment.sql | 4 +- deploy/draft_payment@v6.sql | 183 ++++++++++++++++++++++++++++++++++++ revert/draft_payment.sql | 48 ++++++---- revert/draft_payment@v6.sql | 171 +++++++++++++++++++++++++++++++++ sqitch.plan | 2 + test/draft_payment.sql | 2 +- verify/draft_payment@v6.sql | 7 ++ 7 files changed, 394 insertions(+), 23 deletions(-) create mode 100644 deploy/draft_payment@v6.sql create mode 100644 revert/draft_payment@v6.sql create mode 100644 verify/draft_payment@v6.sql diff --git a/deploy/draft_payment.sql b/deploy/draft_payment.sql index 036438e..c4bba9e 100644 --- a/deploy/draft_payment.sql +++ b/deploy/draft_payment.sql @@ -19,8 +19,6 @@ begin; set search_path to camper, public; -drop function if exists draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]); - create or replace function draft_payment(payment_slug uuid, arrival_date date, departure_date date, campsite_type_slug uuid, num_adults integer, num_teenagers integer, num_children integer, num_dogs integer, zone_preferences text, acsi_card boolean, options option_units[]) returns payment as $$ declare @@ -64,7 +62,7 @@ begin , num_children , sum(cost_per_child * greatest(0, num_children - coalesce(acsi.number_children, 0)))::integer , num_dogs - , sum(case when (num_dogs - coalesce(acsi.number_dogs, 0)) > 0 then coalesce(pet.cost_per_night, 0) else 0 end)::integer + , sum(coalesce(pet.cost_per_night, 0) * greatest(0, num_dogs - coalesce(acsi.number_dogs, 0)))::integer , sum(case when day_num <= tourist_tax_max_days then tourist_tax * num_adults else 0 end)::integer , 0 , currency_code diff --git a/deploy/draft_payment@v6.sql b/deploy/draft_payment@v6.sql new file mode 100644 index 0000000..036438e --- /dev/null +++ b/deploy/draft_payment@v6.sql @@ -0,0 +1,183 @@ +-- Deploy camper:draft_payment to pg +-- requires: roles +-- requires: schema_camper +-- requires: season_calendar +-- requires: season +-- requires: campsite_type +-- requires: campsite_type_pet_cost +-- requires: campsite_type_cost +-- requires: campsite_type_option_cost +-- requires: campsite_type_option +-- requires: payment +-- requires: payment_option +-- requires: company__tourist_tax_max_days +-- requires: acsi +-- requires: acsi_calendar +-- requires: acsi_options + +begin; + +set search_path to camper, public; + +drop function if exists draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]); + +create or replace function draft_payment(payment_slug uuid, arrival_date date, departure_date date, campsite_type_slug uuid, num_adults integer, num_teenagers integer, num_children integer, num_dogs integer, zone_preferences text, acsi_card boolean, options option_units[]) returns payment as +$$ +declare + p payment; +begin + if exists(select 1 from payment where slug = payment_slug and payment_status <> 'draft') then + payment_slug = null; + end if; + insert into payment ( + slug + , company_id + , campsite_type_id + , arrival_date + , departure_date + , subtotal_nights + , number_adults + , subtotal_adults + , number_teenagers + , subtotal_teenagers + , number_children + , subtotal_children + , number_dogs + , subtotal_dogs + , subtotal_tourist_tax + , total + , currency_code + , down_payment_percent + , zone_preferences + , acsi_card + ) + select coalesce(payment_slug, gen_random_uuid()) + , company_id + , campsite_type.campsite_type_id + , arrival_date + , departure_date + , sum(coalesce(acsi.cost_per_night, 0) + cost.cost_per_night * (ceiling((num_adults::numeric + num_teenagers::numeric + num_children::numeric) / max_campers::numeric)::integer - case when acsi.cost_per_night is null then 0 else 1 end))::integer + , num_adults + , sum(cost_per_adult * greatest(0, num_adults - coalesce(acsi.number_adults, 0)))::integer + , num_teenagers + , sum(cost_per_teenager * greatest(0, num_teenagers - coalesce(acsi.number_teenagers, 0)))::integer + , num_children + , sum(cost_per_child * greatest(0, num_children - coalesce(acsi.number_children, 0)))::integer + , num_dogs + , sum(case when (num_dogs - coalesce(acsi.number_dogs, 0)) > 0 then coalesce(pet.cost_per_night, 0) else 0 end)::integer + , sum(case when day_num <= tourist_tax_max_days then tourist_tax * num_adults else 0 end)::integer + , 0 + , currency_code + , case when arrival_date - current_date >= 7 then 0.3 else 1.0 end + , coalesce(zone_preferences, '') + , acsi_card + from generate_series(arrival_date, departure_date - 1, interval '1 day') with ordinality as date(day, day_num) + left join season_calendar on season_range @> date.day::date + left join season using (season_id) + left join campsite_type using (company_id) + left join campsite_type_pet_cost as pet using (campsite_type_id) + left join campsite_type_cost as cost using (campsite_type_id, season_id) + left join company using (company_id) + left join (acsi join acsi_calendar using (campsite_type_id)) as acsi + on acsi_card + and acsi.campsite_type_id = campsite_type.campsite_type_id + and date.day::date <@ acsi_range + where campsite_type.slug = campsite_type_slug + group by company_id + , campsite_type.campsite_type_id + , currency_code + on conflict (slug) do update + set company_id = excluded.company_id + , campsite_type_id = excluded.campsite_type_id + , arrival_date = excluded.arrival_date + , departure_date = excluded.departure_date + , subtotal_nights = excluded.subtotal_nights + , number_adults = excluded.number_adults + , subtotal_adults = excluded.subtotal_adults + , number_teenagers = excluded.number_teenagers + , subtotal_teenagers = excluded.subtotal_teenagers + , number_children = excluded.number_children + , subtotal_children = excluded.subtotal_children + , number_dogs = excluded.number_dogs + , subtotal_dogs = excluded.subtotal_dogs + , subtotal_tourist_tax = excluded.subtotal_tourist_tax + , total = excluded.total + , currency_code = excluded.currency_code + , down_payment_percent = excluded.down_payment_percent + , zone_preferences = excluded.zone_preferences + , acsi_card = excluded.acsi_card + , updated_at = current_timestamp + returning * + into p + ; + + if array_length(coalesce(options, array[]::option_units[]), 1) > 0 then + delete + from payment_option + where payment_id = p.payment_id + and campsite_type_option_id not in ( + select campsite_type_option_id + from unnest(options) as option(campsite_type_option_id, units) + ); + + insert into payment_option ( + payment_id + , campsite_type_option_id + , units + , subtotal + ) + select p.payment_id + , campsite_type_option.campsite_type_option_id + , option.units + , case when per_night then sum(cost * greatest(0, option.units - coalesce(acsi_option.units, 0)))::integer else max(cost * greatest(0, option.units - coalesce(acsi_option.units, 0)))::integer end + from generate_series(arrival_date, departure_date - 1, interval '1 day') as date(day) + join season_calendar on season_range @> date.day::date + join campsite_type_option_cost using (season_id) + join campsite_type_option using (campsite_type_option_id) + join unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) + left join acsi_calendar on acsi_card and day::date <@ acsi_range + left join acsi_option on acsi_option.campsite_type_id = acsi_calendar.campsite_type_id and acsi_option.campsite_type_option_id = campsite_type_option.campsite_type_option_id + group by campsite_type_option.campsite_type_option_id + , option.units + , per_night + on conflict (payment_id, campsite_type_option_id) do update + set units = excluded.units + , subtotal = excluded.subtotal + ; + + with option as ( + select sum(subtotal)::integer as subtotal + from payment_option + where payment_id = p.payment_id + ) + update payment + set total = subtotal_nights + subtotal_adults + subtotal_teenagers + subtotal_children + subtotal_dogs + subtotal_tourist_tax + coalesce(option.subtotal, 0) + from option + where payment_id = p.payment_id + returning total into p.total + ; + else + delete + from payment_option + where payment_id = p.payment_id; + + update payment + set total = subtotal_nights + subtotal_adults + subtotal_teenagers + subtotal_children + subtotal_dogs + subtotal_tourist_tax + where payment_id = p.payment_id + returning total into p.total + ; + end if; + + + return p; +end; +$$ + language plpgsql +; + +revoke execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) from public; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) to guest; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) to employee; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) to admin; + +commit; diff --git a/revert/draft_payment.sql b/revert/draft_payment.sql index 0321fb7..01dfe7e 100644 --- a/revert/draft_payment.sql +++ b/revert/draft_payment.sql @@ -11,14 +11,15 @@ -- requires: payment -- requires: payment_option -- requires: company__tourist_tax_max_days +-- requires: acsi +-- requires: acsi_calendar +-- requires: acsi_options begin; set search_path to camper, public; -drop function if exists draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]); - -create or replace function draft_payment(payment_slug uuid, arrival_date date, departure_date date, campsite_type_slug uuid, num_adults integer, num_teenagers integer, num_children integer, num_dogs integer, zone_preferences text, options option_units[]) returns payment as +create or replace function draft_payment(payment_slug uuid, arrival_date date, departure_date date, campsite_type_slug uuid, num_adults integer, num_teenagers integer, num_children integer, num_dogs integer, zone_preferences text, acsi_card boolean, options option_units[]) returns payment as $$ declare p payment; @@ -46,26 +47,28 @@ begin , currency_code , down_payment_percent , zone_preferences + , acsi_card ) select coalesce(payment_slug, gen_random_uuid()) , company_id - , campsite_type_id + , campsite_type.campsite_type_id , arrival_date , departure_date - , sum(cost.cost_per_night * ceiling((num_adults::numeric + num_teenagers::numeric + num_children::numeric) / max_campers::numeric)::integer)::integer + , sum(coalesce(acsi.cost_per_night, 0) + cost.cost_per_night * (ceiling((num_adults::numeric + num_teenagers::numeric + num_children::numeric) / max_campers::numeric)::integer - case when acsi.cost_per_night is null then 0 else 1 end))::integer , num_adults - , sum(cost_per_adult * num_adults)::integer + , sum(cost_per_adult * greatest(0, num_adults - coalesce(acsi.number_adults, 0)))::integer , num_teenagers - , sum(cost_per_teenager * num_teenagers)::integer + , sum(cost_per_teenager * greatest(0, num_teenagers - coalesce(acsi.number_teenagers, 0)))::integer , num_children - , sum(cost_per_child * num_children)::integer + , sum(cost_per_child * greatest(0, num_children - coalesce(acsi.number_children, 0)))::integer , num_dogs - , sum(case when num_dogs > 0 then coalesce(pet.cost_per_night, 0) else 0 end)::integer + , sum(case when (num_dogs - coalesce(acsi.number_dogs, 0)) > 0 then coalesce(pet.cost_per_night, 0) else 0 end)::integer , sum(case when day_num <= tourist_tax_max_days then tourist_tax * num_adults else 0 end)::integer , 0 , currency_code , case when arrival_date - current_date >= 7 then 0.3 else 1.0 end , coalesce(zone_preferences, '') + , acsi_card from generate_series(arrival_date, departure_date - 1, interval '1 day') with ordinality as date(day, day_num) left join season_calendar on season_range @> date.day::date left join season using (season_id) @@ -73,9 +76,13 @@ begin left join campsite_type_pet_cost as pet using (campsite_type_id) left join campsite_type_cost as cost using (campsite_type_id, season_id) left join company using (company_id) + left join (acsi join acsi_calendar using (campsite_type_id)) as acsi + on acsi_card + and acsi.campsite_type_id = campsite_type.campsite_type_id + and date.day::date <@ acsi_range where campsite_type.slug = campsite_type_slug group by company_id - , campsite_type_id + , campsite_type.campsite_type_id , currency_code on conflict (slug) do update set company_id = excluded.company_id @@ -96,6 +103,7 @@ begin , currency_code = excluded.currency_code , down_payment_percent = excluded.down_payment_percent , zone_preferences = excluded.zone_preferences + , acsi_card = excluded.acsi_card , updated_at = current_timestamp returning * into p @@ -117,16 +125,18 @@ begin , subtotal ) select p.payment_id - , campsite_type_option_id - , units - , case when per_night then sum(cost * units)::integer else max(cost * units)::integer end + , campsite_type_option.campsite_type_option_id + , option.units + , case when per_night then sum(cost * greatest(0, option.units - coalesce(acsi_option.units, 0)))::integer else max(cost * greatest(0, option.units - coalesce(acsi_option.units, 0)))::integer end from generate_series(arrival_date, departure_date - 1, interval '1 day') as date(day) join season_calendar on season_range @> date.day::date join campsite_type_option_cost using (season_id) join campsite_type_option using (campsite_type_option_id) join unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) - group by campsite_type_option_id - , units + left join acsi_calendar on acsi_card and day::date <@ acsi_range + left join acsi_option on acsi_option.campsite_type_id = acsi_calendar.campsite_type_id and acsi_option.campsite_type_option_id = campsite_type_option.campsite_type_option_id + group by campsite_type_option.campsite_type_option_id + , option.units , per_night on conflict (payment_id, campsite_type_option_id) do update set units = excluded.units @@ -163,9 +173,9 @@ $$ language plpgsql ; -revoke execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) from public; -grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) to guest; -grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) to employee; -grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) to admin; +revoke execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) from public; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) to guest; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) to employee; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]) to admin; commit; diff --git a/revert/draft_payment@v6.sql b/revert/draft_payment@v6.sql new file mode 100644 index 0000000..0321fb7 --- /dev/null +++ b/revert/draft_payment@v6.sql @@ -0,0 +1,171 @@ +-- Deploy camper:draft_payment to pg +-- requires: roles +-- requires: schema_camper +-- requires: season_calendar +-- requires: season +-- requires: campsite_type +-- requires: campsite_type_pet_cost +-- requires: campsite_type_cost +-- requires: campsite_type_option_cost +-- requires: campsite_type_option +-- requires: payment +-- requires: payment_option +-- requires: company__tourist_tax_max_days + +begin; + +set search_path to camper, public; + +drop function if exists draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, option_units[]); + +create or replace function draft_payment(payment_slug uuid, arrival_date date, departure_date date, campsite_type_slug uuid, num_adults integer, num_teenagers integer, num_children integer, num_dogs integer, zone_preferences text, options option_units[]) returns payment as +$$ +declare + p payment; +begin + if exists(select 1 from payment where slug = payment_slug and payment_status <> 'draft') then + payment_slug = null; + end if; + insert into payment ( + slug + , company_id + , campsite_type_id + , arrival_date + , departure_date + , subtotal_nights + , number_adults + , subtotal_adults + , number_teenagers + , subtotal_teenagers + , number_children + , subtotal_children + , number_dogs + , subtotal_dogs + , subtotal_tourist_tax + , total + , currency_code + , down_payment_percent + , zone_preferences + ) + select coalesce(payment_slug, gen_random_uuid()) + , company_id + , campsite_type_id + , arrival_date + , departure_date + , sum(cost.cost_per_night * ceiling((num_adults::numeric + num_teenagers::numeric + num_children::numeric) / max_campers::numeric)::integer)::integer + , num_adults + , sum(cost_per_adult * num_adults)::integer + , num_teenagers + , sum(cost_per_teenager * num_teenagers)::integer + , num_children + , sum(cost_per_child * num_children)::integer + , num_dogs + , sum(case when num_dogs > 0 then coalesce(pet.cost_per_night, 0) else 0 end)::integer + , sum(case when day_num <= tourist_tax_max_days then tourist_tax * num_adults else 0 end)::integer + , 0 + , currency_code + , case when arrival_date - current_date >= 7 then 0.3 else 1.0 end + , coalesce(zone_preferences, '') + from generate_series(arrival_date, departure_date - 1, interval '1 day') with ordinality as date(day, day_num) + left join season_calendar on season_range @> date.day::date + left join season using (season_id) + left join campsite_type using (company_id) + left join campsite_type_pet_cost as pet using (campsite_type_id) + left join campsite_type_cost as cost using (campsite_type_id, season_id) + left join company using (company_id) + where campsite_type.slug = campsite_type_slug + group by company_id + , campsite_type_id + , currency_code + on conflict (slug) do update + set company_id = excluded.company_id + , campsite_type_id = excluded.campsite_type_id + , arrival_date = excluded.arrival_date + , departure_date = excluded.departure_date + , subtotal_nights = excluded.subtotal_nights + , number_adults = excluded.number_adults + , subtotal_adults = excluded.subtotal_adults + , number_teenagers = excluded.number_teenagers + , subtotal_teenagers = excluded.subtotal_teenagers + , number_children = excluded.number_children + , subtotal_children = excluded.subtotal_children + , number_dogs = excluded.number_dogs + , subtotal_dogs = excluded.subtotal_dogs + , subtotal_tourist_tax = excluded.subtotal_tourist_tax + , total = excluded.total + , currency_code = excluded.currency_code + , down_payment_percent = excluded.down_payment_percent + , zone_preferences = excluded.zone_preferences + , updated_at = current_timestamp + returning * + into p + ; + + if array_length(coalesce(options, array[]::option_units[]), 1) > 0 then + delete + from payment_option + where payment_id = p.payment_id + and campsite_type_option_id not in ( + select campsite_type_option_id + from unnest(options) as option(campsite_type_option_id, units) + ); + + insert into payment_option ( + payment_id + , campsite_type_option_id + , units + , subtotal + ) + select p.payment_id + , campsite_type_option_id + , units + , case when per_night then sum(cost * units)::integer else max(cost * units)::integer end + from generate_series(arrival_date, departure_date - 1, interval '1 day') as date(day) + join season_calendar on season_range @> date.day::date + join campsite_type_option_cost using (season_id) + join campsite_type_option using (campsite_type_option_id) + join unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) + group by campsite_type_option_id + , units + , per_night + on conflict (payment_id, campsite_type_option_id) do update + set units = excluded.units + , subtotal = excluded.subtotal + ; + + with option as ( + select sum(subtotal)::integer as subtotal + from payment_option + where payment_id = p.payment_id + ) + update payment + set total = subtotal_nights + subtotal_adults + subtotal_teenagers + subtotal_children + subtotal_dogs + subtotal_tourist_tax + coalesce(option.subtotal, 0) + from option + where payment_id = p.payment_id + returning total into p.total + ; + else + delete + from payment_option + where payment_id = p.payment_id; + + update payment + set total = subtotal_nights + subtotal_adults + subtotal_teenagers + subtotal_children + subtotal_dogs + subtotal_tourist_tax + where payment_id = p.payment_id + returning total into p.total + ; + end if; + + + return p; +end; +$$ + language plpgsql +; + +revoke execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) from public; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) to guest; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) to employee; +grant execute on function draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, option_units[]) to admin; + +commit; diff --git a/sqitch.plan b/sqitch.plan index de27c47..63d792e 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -275,3 +275,5 @@ ready_payment [ready_payment@v5 payment__acsi_card] 2024-03-14T18:31:26Z jordi f payment_customer__-acsi_card [payment__acsi_card] 2024-03-14T18:43:31Z jordi fita mas # Remove the acsi_card field from payment_customer draft_payment [draft_payment@v5 acsi acsi_calendar acsi_option payment__acsi_card payment_customer__-acsi_card] 2024-03-14T18:05:25Z jordi fita mas # Include ACSI in payment drafting computation @v6 2024-03-20T17:10:00Z jordi fita mas # Tag version 6 + +draft_payment [draft_payment@v6] 2024-03-20T17:11:41Z jordi fita mas # Use the number of dogs to compute the total, no just as if it were a boolean diff --git a/test/draft_payment.sql b/test/draft_payment.sql index 80b6425..8475a72 100644 --- a/test/draft_payment.sql +++ b/test/draft_payment.sql @@ -155,7 +155,7 @@ select lives_ok( select bag_eq( $$ select company_id, campsite_type_id, arrival_date, departure_date, subtotal_nights, number_adults, subtotal_adults, number_teenagers, subtotal_teenagers, number_children, subtotal_children, number_dogs, subtotal_dogs, subtotal_tourist_tax, total, currency_code, down_payment_percent, zone_preferences, payment_status, created_at, updated_at from payment $$, - $$ values (2, 12, current_date + 58, current_date + 65, 3200, 2, 10420, 4, 20840, 6, 25080, 3, 2450, 4900, 79160, 'EUR', 0.3, 'pref I before E', 'draft', '2024-01-01 01:01:01', current_timestamp) + $$ values (2, 12, current_date + 58, current_date + 65, 3200, 2, 10420, 4, 20840, 6, 25080, 3, 7350, 4900, 84060, 'EUR', 0.3, 'pref I before E', 'draft', '2024-01-01 01:01:01', current_timestamp) , (2, 14, current_date + 59, current_date + 64, 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) , (2, 14, current_date + 10, current_date + 58, 1632000, 2, 0, 3, 0, 4, 0, 0, 0, 4900, 1636900, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) , (2, 14, current_date + 6, current_date + 11, 85000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 86750, 'EUR', 1.0, '', 'draft', current_timestamp, current_timestamp) diff --git a/verify/draft_payment@v6.sql b/verify/draft_payment@v6.sql new file mode 100644 index 0000000..139cc03 --- /dev/null +++ b/verify/draft_payment@v6.sql @@ -0,0 +1,7 @@ +-- Verify camper:draft_payment on pg + +begin; + +select has_function_privilege('camper.draft_payment(uuid, date, date, uuid, integer, integer, integer, integer, text, boolean, camper.option_units[])', 'execute'); + +rollback;