From 746aa013d30c53bfdc5645e4cc3ef1c1e06cc3b1 Mon Sep 17 00:00:00 2001 From: jordi fita mas Date: Wed, 3 Apr 2024 12:18:54 +0200 Subject: [PATCH] Group ACSI options and allow for usage in different groups MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit It turns out that, **this time**, at least, the way to compute the discount is not by “the more expensive”, but “the more expensive _in a given group_”. However, there are a couple of options, such as motorhome, that can be in different groups but only must be used once. --- deploy/acsi_option__option_group.sql | 21 +++ deploy/draft_payment.sql | 25 ++-- deploy/draft_payment@v7.sql | 194 +++++++++++++++++++++++++++ revert/acsi_option__option_group.sql | 16 +++ revert/draft_payment.sql | 19 ++- revert/draft_payment@v7.sql | 181 +++++++++++++++++++++++++ sqitch.plan | 3 + test/acsi_option.sql | 9 +- test/draft_payment.sql | 86 ++++++++---- verify/acsi_option__option_group.sql | 9 ++ verify/draft_payment@v7.sql | 7 + 11 files changed, 531 insertions(+), 39 deletions(-) create mode 100644 deploy/acsi_option__option_group.sql create mode 100644 deploy/draft_payment@v7.sql create mode 100644 revert/acsi_option__option_group.sql create mode 100644 revert/draft_payment@v7.sql create mode 100644 verify/acsi_option__option_group.sql create mode 100644 verify/draft_payment@v7.sql diff --git a/deploy/acsi_option__option_group.sql b/deploy/acsi_option__option_group.sql new file mode 100644 index 0000000..94b6539 --- /dev/null +++ b/deploy/acsi_option__option_group.sql @@ -0,0 +1,21 @@ +-- Deploy camper:acsi_option__option_group to pg +-- requires: acsi_option + +begin; + +set search_path to camper, public; + +alter table acsi_option + add column option_group integer not null default 0 +; + +alter table acsi_option + drop constraint if exists acsi_option_pkey +; + +alter table acsi_option + add primary key (campsite_type_id, campsite_type_option_id, option_group) +, alter column option_group drop default +; + +commit; diff --git a/deploy/draft_payment.sql b/deploy/draft_payment.sql index b344d91..5d73090 100644 --- a/deploy/draft_payment.sql +++ b/deploy/draft_payment.sql @@ -13,7 +13,8 @@ -- requires: company__tourist_tax_max_days -- requires: acsi -- requires: acsi_calendar --- requires: acsi_options +-- requires: acsi_option +-- requires: acsi_option__option_group begin; @@ -119,15 +120,21 @@ begin ); with discountable_acsi_option as ( - select day, campsite_type_option_id, units + select distinct day, campsite_type_option_id, units from ( - select day, campsite_type_option_id, acsi_option.units, row_number() over (partition by day order by cost desc) as rn - 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 unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) - join acsi_calendar on acsi_card and day::date <@ acsi_range - join acsi_option as acsi_option using (campsite_type_option_id) + select day, campsite_type_option_id, units, row_number() over (partition by day, option_group order by cost desc) as rn + from ( + select day, campsite_type_option_id, units, cost, min(option_group) option_group from ( + select day, campsite_type_option_id, acsi_option.units, cost, option_group, count(*) over (partition by day, option_group) > 1 as already_used + 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 unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) + join acsi_calendar on acsi_card and day::date <@ acsi_range + join acsi_option as acsi_option using (campsite_type_option_id) + ) as with_count + group by day, campsite_type_option_id, units, cost, already_used + ) as by_group ) as discountable where acsi_card and rn = 1 diff --git a/deploy/draft_payment@v7.sql b/deploy/draft_payment@v7.sql new file mode 100644 index 0000000..b344d91 --- /dev/null +++ b/deploy/draft_payment@v7.sql @@ -0,0 +1,194 @@ +-- 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; + +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(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 + , 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) + ); + + with discountable_acsi_option as ( + select day, campsite_type_option_id, units + from ( + select day, campsite_type_option_id, acsi_option.units, row_number() over (partition by day order by cost desc) as rn + 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 unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) + join acsi_calendar on acsi_card and day::date <@ acsi_range + join acsi_option as acsi_option using (campsite_type_option_id) + ) as discountable + where acsi_card + and rn = 1 + ) + 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 discountable_acsi_option as acsi_option using (day, 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/acsi_option__option_group.sql b/revert/acsi_option__option_group.sql new file mode 100644 index 0000000..0669303 --- /dev/null +++ b/revert/acsi_option__option_group.sql @@ -0,0 +1,16 @@ +-- Revert camper:acsi_option__option_group from pg + +begin; + +set search_path to camper, public; + +alter table acsi_option + drop constraint if exists acsi_option_pkey +; + +alter table camper.acsi_option + add primary key (campsite_type_id, campsite_type_option_id) +, drop column if exists option_group +; + +commit; diff --git a/revert/draft_payment.sql b/revert/draft_payment.sql index 01dfe7e..b344d91 100644 --- a/revert/draft_payment.sql +++ b/revert/draft_payment.sql @@ -62,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 @@ -118,6 +118,20 @@ begin from unnest(options) as option(campsite_type_option_id, units) ); + with discountable_acsi_option as ( + select day, campsite_type_option_id, units + from ( + select day, campsite_type_option_id, acsi_option.units, row_number() over (partition by day order by cost desc) as rn + 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 unnest(options) as option(campsite_type_option_id, units) using (campsite_type_option_id) + join acsi_calendar on acsi_card and day::date <@ acsi_range + join acsi_option as acsi_option using (campsite_type_option_id) + ) as discountable + where acsi_card + and rn = 1 + ) insert into payment_option ( payment_id , campsite_type_option_id @@ -133,8 +147,7 @@ begin 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 + left join discountable_acsi_option as acsi_option using (day, campsite_type_option_id) group by campsite_type_option.campsite_type_option_id , option.units , per_night diff --git a/revert/draft_payment@v7.sql b/revert/draft_payment@v7.sql new file mode 100644 index 0000000..01dfe7e --- /dev/null +++ b/revert/draft_payment@v7.sql @@ -0,0 +1,181 @@ +-- 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; + +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/sqitch.plan b/sqitch.plan index d48023f..f98c802 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -278,3 +278,6 @@ draft_payment [draft_payment@v5 acsi acsi_calendar acsi_option payment__acsi_car 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 @v7 2024-04-03T07:32:10Z jordi fita mas # Tag version 7 + +acsi_option__option_group [acsi_option] 2024-04-03T07:55:37Z jordi fita mas # Add option_group column to acsi_option +draft_payment [draft_payment@v7 acsi_option__option_group] 2024-04-03T08:15:40Z jordi fita mas # Take option_group in account when discounting ACSI options in draft_payment diff --git a/test/acsi_option.sql b/test/acsi_option.sql index 52d82d6..c08c819 100644 --- a/test/acsi_option.sql +++ b/test/acsi_option.sql @@ -5,13 +5,13 @@ reset client_min_messages; begin; -select plan(23); +select plan(27); set search_path to camper, public; select has_table('acsi_option'); select has_pk('acsi_option'); -select col_is_pk('acsi_option', array['campsite_type_id', 'campsite_type_option_id']); +select col_is_pk('acsi_option', array['campsite_type_id', 'campsite_type_option_id', 'option_group']); select table_privs_are('acsi_option', 'guest', array['SELECT']); select table_privs_are('acsi_option', 'employee', array['SELECT']); select table_privs_are('acsi_option', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); @@ -31,6 +31,11 @@ select col_type_is('acsi_option', 'campsite_type_option_id', 'integer'); select col_not_null('acsi_option', 'campsite_type_option_id'); select col_hasnt_default('acsi_option', 'campsite_type_option_id'); +select has_column('acsi_option', 'option_group'); +select col_type_is('acsi_option', 'option_group', 'integer'); +select col_not_null('acsi_option', 'option_group'); +select col_hasnt_default('acsi_option', 'option_group'); + select has_column('acsi_option', 'units'); select col_type_is('acsi_option', 'units', 'positive_integer'); select col_not_null('acsi_option', 'units'); diff --git a/test/draft_payment.sql b/test/draft_payment.sql index 8bab09d..a63c0d9 100644 --- a/test/draft_payment.sql +++ b/test/draft_payment.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(17); +select plan(20); set search_path to camper, public; @@ -82,20 +82,28 @@ values (12, 350) insert into campsite_type_option (campsite_type_option_id, campsite_type_id, name, range, per_night) values (16, 12, 'Big tent', '[0, 4)', true) - , (18, 12, 'Car', '[0, 4)', true) + , (18, 12, 'Small tent', '[0, 4)', true) , (20, 12, 'Electricity', '[0, 5)', false) + , (22, 12, 'Car', '[0, 4)', true) + , (24, 12, 'Autocaravan', '[0, 4)', true) ; insert into campsite_type_option_cost (campsite_type_option_id, season_id, cost) values (16, 4, 800) , (16, 6, 720) , (16, 8, 620) - , (18, 4, 700) - , (18, 6, 630) - , (18, 8, 530) + , (18, 4, 620) + , (18, 6, 550) + , (18, 8, 500) , (20, 4, 690) , (20, 6, 610) , (20, 8, 590) + , (22, 4, 700) + , (22, 6, 630) + , (22, 8, 530) + , (24, 4, 900) + , (24, 6, 750) + , (24, 8, 650) ; alter table payment alter column payment_id restart with 26; @@ -118,9 +126,12 @@ values (12, daterange(current_date + 60, current_date + 61)) , (12, daterange(current_date + 64, current_date + 65)) ; -insert into acsi_option (campsite_type_id, campsite_type_option_id, units) -values (12, 16, 1) - , (12, 18, 1) +insert into acsi_option (campsite_type_id, campsite_type_option_id, option_group, units) +values (12, 22, 0, 1) + , (12, 24, 0, 1) + , (12, 16, 1, 1) + , (12, 18, 1, 1) + , (12, 24, 1, 1) ; select lives_ok( @@ -153,30 +164,55 @@ select lives_ok( 'Should be able to draft a payment for plots with ACSI discount during the days that is valid' ); +select lives_ok( + $$ select draft_payment(null, current_date + 60, current_date + 61, 'c1b6f4fc-32c1-4cd5-b796-0c5059152a52', 2, 0, 0, 1, '', true, array[(16, 1), (22, 1)]::option_units[]) $$, + 'Should be able to draft a payment for plots that everything is under ACSI discount' +); + +select lives_ok( + $$ select draft_payment(null, current_date + 60, current_date + 61, 'c1b6f4fc-32c1-4cd5-b796-0c5059152a52', 2, 0, 0, 1, '', true, array[(16, 1), (24, 1)]::option_units[]) $$, + 'Should be able to draft a payment for plots that everything except big tent is under ACSI discount' +); + +select lives_ok( + $$ select draft_payment(null, current_date + 60, current_date + 61, 'c1b6f4fc-32c1-4cd5-b796-0c5059152a52', 2, 0, 0, 1, '', true, array[(16, 1), (22, 1), (24, 1)]::option_units[]) $$, + 'Should be able to draft a payment for plots that everything except car is under ACSI discount' +); + 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, 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) - , (2, 12, current_date + 61, current_date + 62, 0, 1, 0, 0, 0, 0, 0, 0, 0, 0, 0, 'USD', 1.0, '', 'pending', '2024-01-01 02:02:02', '2024-01-01 02:02:02') - , (2, 14, current_date + 31, current_date + 36, 85000, 2, 0, 1, 0, 1, 0, 1, 0, 3500, 96000, 'EUR', 0.3, 'under a tree', 'draft', current_timestamp, current_timestamp) - , (2, 12, current_date + 58, current_date + 65, 6000, 3, 12830, 1, 5210, 1, 4180, 1, 1750, 7350, 62290, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) + $$ select payment_id, 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 (22, 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) + , (24, 2, 12, current_date + 61, current_date + 62, 0, 1, 0, 0, 0, 0, 0, 0, 0, 0, 0, 'USD', 1.0, '', 'pending', '2024-01-01 02:02:02', '2024-01-01 02:02:02') + , (26, 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) + , (27, 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) + , (28, 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) + , (30, 2, 14, current_date + 31, current_date + 36, 85000, 2, 0, 1, 0, 1, 0, 1, 0, 3500, 95600, 'EUR', 0.3, 'under a tree', 'draft', current_timestamp, current_timestamp) + , (31, 2, 12, current_date + 58, current_date + 65, 6000, 3, 12830, 1, 5210, 1, 4180, 1, 1750, 7350, 60760, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) + , (32, 2, 12, current_date + 60, current_date + 61, 2300, 2, 0, 0, 0, 0, 0, 1, 0, 700, 3000, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) + , (33, 2, 12, current_date + 60, current_date + 61, 2300, 2, 0, 0, 0, 0, 0, 1, 0, 700, 3720, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) + , (34, 2, 12, current_date + 60, current_date + 61, 2300, 2, 0, 0, 0, 0, 0, 1, 0, 700, 3630, 'EUR', 0.3, '', 'draft', current_timestamp, current_timestamp) $$, 'Should have added and updated payments' ); select bag_eq( - $$ select case payment_id when 22 then 'a' when 24 then 'b' else 'c' end, campsite_type_option_id, units, subtotal from payment_option $$, - $$ values ('a', 16, 2, 10200) - , ('a', 20, 3, 2070) - , ('b', 16, 2, 0) - , ('c', 16, 1, 4000) - , ('c', 18, 1, 3500) - , ('c', 16, 2, 8860) -- This is the most expensive, thus the only discounted - , ('c', 18, 3, 13350) -- No discount - , ('c', 20, 4, 2760) -- This is not even in ACSI + $$ select payment_id, campsite_type_option_id, units, subtotal from payment_option $$, + $$ values (22, 16, 2, 10200) + , (22, 20, 3, 2070) + , (24, 16, 2, 0) + , (30, 16, 1, 4000) + , (30, 18, 1, 3100) + , (31, 16, 2, 8860) -- This is the most expensive, thus the only discounted + , (31, 18, 3, 11820) -- No discount + , (31, 20, 4, 2760) -- This is not even in ACSI + , (32, 16, 1, 0) -- ACSI discount + , (32, 22, 1, 0) -- ACSI discount + , (33, 16, 1, 720) -- No discount because already discounted in option 24 + , (33, 24, 1, 0) -- ACSI discount + , (34, 16, 1, 0) -- Discount because opiont 24 was already “resolved” against 22 + , (34, 24, 1, 0) -- ACSI discount + , (34, 22, 1, 630) -- No discount because it is cheaper than option 24 $$, 'Should have added, updated, and removed payment options' ); diff --git a/verify/acsi_option__option_group.sql b/verify/acsi_option__option_group.sql new file mode 100644 index 0000000..32b1bda --- /dev/null +++ b/verify/acsi_option__option_group.sql @@ -0,0 +1,9 @@ +-- Verify camper:acsi_option__option_group on pg + +begin; + +select option_group +from camper.acsi_option +where false; + +rollback; diff --git a/verify/draft_payment@v7.sql b/verify/draft_payment@v7.sql new file mode 100644 index 0000000..139cc03 --- /dev/null +++ b/verify/draft_payment@v7.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;