162 lines
5.5 KiB
PL/PgSQL
162 lines
5.5 KiB
PL/PgSQL
-- 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
|
|
|
|
begin;
|
|
|
|
set search_path to camper, public;
|
|
|
|
create type option_units as (option_id integer, units integer);
|
|
|
|
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
|
|
, 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(tourist_tax * num_adults)::integer
|
|
, 0
|
|
, coalesce(zone_preferences, '')
|
|
from generate_series(arrival_date, departure_date - 1, interval '1 day') as date(day)
|
|
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
|
|
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
|
|
, 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
|
|
;
|
|
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
|
|
;
|
|
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;
|