-- 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;