Allow many campsites for each reservation

This is actually only used for plots, but, of course, it means that
every booking now can potentially have many booked campsites, and have
to create a relation for it.

I now have a conundrum regarding stay dates: i need them to be in the
same table as the campsite_id, because constraints only work on a single
relation and without the dates i can not make sure that i am not
overbooking a given campsite; but, on the other hand, all campsites
under the same booking must be for the same dates.

Where does stay belong, then? In booking or booking_campsite? If in
booking then i can not have a constraint that most assuredly will bite
me in the back, but if in booking_campsite then each campsite could
potentially have different dates.

As far as i can see, i can not use a exclude constraint with <> for
dates in booking_campsite to ensure that all rows with the same
booking_id have the same stay (i.e., exclude those that have a different
stay for the same booking_id).

For now, the say is in **both** relations: in booking, because i need it
when it is a prebooking, at least, and in booking_campsite for the
aforementioned constraint requirements.

Will this come back and bite me? Yes, it will. But what can i do?
This commit is contained in:
jordi fita mas 2024-04-21 21:28:41 +02:00
parent cba892c4c0
commit 7eb718dfd9
11 changed files with 172 additions and 63 deletions

View File

@ -1487,23 +1487,34 @@ select translate_surroundings_ad(52, 'es', '¡Ven a hacer barranquismo en Sadern
select translate_surroundings_ad(52, 'fr', 'Venez faire du canyoning à Sadernes !', 'Réservez votre journée'); select translate_surroundings_ad(52, 'fr', 'Venez faire du canyoning à Sadernes !', 'Réservez votre journée');
alter table booking alter column booking_id restart with 122; alter table booking alter column booking_id restart with 122;
insert into booking (company_id, campsite_type_id, holder_name, stay, number_dogs, acsi_card, booking_status)
insert into booking (company_id, campsite_type_id, campsite_id, holder_name, stay, number_dogs, acsi_card, booking_status) values (52, 72, 'Juli Verd', daterange((current_date + interval '23 days')::date, (current_date + interval '25 days')::date), 0, false, 'created')
values (52, 72, null, 'Juli Verd', daterange((current_date + interval '23 days')::date, (current_date + interval '25 days')::date), 0, false, 'created') , (52, 72, 'Camèlia Vermella', daterange((current_date + interval '7 days')::date, (current_date + interval '8 days')::date), 0, false, 'created')
, (52, 72, null, 'Camèlia Vermella', daterange((current_date + interval '7 days')::date, (current_date + interval '8 days')::date), 0, false, 'created') , (52, 72, 'Margarita Blanca', daterange((current_date + interval '7 days')::date, (current_date + interval '8 days')::date), 0, false, 'invoiced')
, (52, 72, 90, 'Margarita Blanca', daterange((current_date + interval '7 days')::date, (current_date + interval '8 days')::date), 0, false, 'invoiced') , (52, 72, 'Rosa Blava', daterange((current_date + interval '8 days')::date, (current_date + interval '11 days')::date), 0, false, 'checked-in')
, (52, 72, 90, 'Rosa Blava', daterange((current_date + interval '8 days')::date, (current_date + interval '11 days')::date), 0, false, 'checked-in') , (52, 72, 'Calèndula Groga', daterange((current_date + interval '14 days')::date, (current_date + interval '21 days')::date), 0, false, 'confirmed')
, (52, 72, 90, 'Calèndula Groga', daterange((current_date + interval '14 days')::date, (current_date + interval '21 days')::date), 0, false, 'confirmed') , (52, 72, 'Jacint Violeta', daterange((current_date + interval '9 days')::date, (current_date + interval '13 days')::date), 0, false, 'checked-in')
, (52, 72, 91, 'Jacint Violeta', daterange((current_date + interval '9 days')::date, (current_date + interval '13 days')::date), 0, false, 'checked-in') , (52, 72, 'Hortènsia Grisa', daterange((current_date + interval '4 days')::date, (current_date + interval '8 days')::date), 0, false, 'invoiced')
, (52, 72, 92, 'Hortènsia Grisa', daterange((current_date + interval '4 days')::date, (current_date + interval '8 days')::date), 0, false, 'invoiced') , (52, 72, 'Pere Gil', daterange((current_date + interval '9 days')::date, (current_date + interval '19 days')::date), 1, true, 'confirmed')
, (52, 72, 93, 'Pere Gil', daterange((current_date + interval '9 days')::date, (current_date + interval '19 days')::date), 1, true, 'confirmed') , (52, 72, 'Juli Verd', daterange((current_date + interval '11 days')::date, (current_date + interval '13 days')::date), 0, false, 'confirmed')
, (52, 72, 94, 'Juli Verd', daterange((current_date + interval '11 days')::date, (current_date + interval '13 days')::date), 0, false, 'confirmed') , (52, 72, 'Camèlia Vermella', daterange((current_date + interval '13 days')::date, (current_date + interval '15 days')::date), 0, false, 'confirmed')
, (52, 72, 94, 'Camèlia Vermella', daterange((current_date + interval '13 days')::date, (current_date + interval '15 days')::date), 0, false, 'confirmed') , (52, 72, 'Valeriana Rosa', daterange((current_date + interval '15 days')::date, (current_date + interval '17 days')::date), 0, false, 'confirmed')
, (52, 72, 94, 'Valeriana Rosa', daterange((current_date + interval '15 days')::date, (current_date + interval '17 days')::date), 0, false, 'confirmed') , (52, 72, 'Pere Gil', daterange((current_date + interval '24 days')::date, (current_date + interval '25 days')::date), 1, true, 'cancelled')
, (52, 72, null, 'Pere Gil', daterange((current_date + interval '24 days')::date, (current_date + interval '25 days')::date), 1, true, 'cancelled') , (52, 72, 'Valeriana Rosa', daterange((current_date + interval '3 days')::date, (current_date + interval '8 days')::date), 0, true, 'cancelled')
, (52, 72, 83, 'Valeriana Rosa', daterange((current_date + interval '3 days')::date, (current_date + interval '8 days')::date), 0, true, 'cancelled')
; ;
insert into booking_campsite (booking_id, campsite_id, stay)
values (124, 90, daterange((current_date + interval '7 days')::date, (current_date + interval '8 days')::date))
, (124, 94, daterange((current_date + interval '7 days')::date, (current_date + interval '8 days')::date))
, (125, 90, daterange((current_date + interval '8 days')::date, (current_date + interval '11 days')::date))
, (126, 90, daterange((current_date + interval '14 days')::date, (current_date + interval '21 days')::date))
, (127, 91, daterange((current_date + interval '9 days')::date, (current_date + interval '13 days')::date))
, (128, 92, daterange((current_date + interval '4 days')::date, (current_date + interval '8 days')::date))
, (129, 93, daterange((current_date + interval '9 days')::date, (current_date + interval '19 days')::date))
, (130, 94, daterange((current_date + interval '11 days')::date, (current_date + interval '13 days')::date))
, (131, 94, daterange((current_date + interval '13 days')::date, (current_date + interval '15 days')::date))
, (132, 94, daterange((current_date + interval '15 days')::date, (current_date + interval '17 days')::date))
;
alter table amenity alter column amenity_id restart with 132; alter table amenity alter column amenity_id restart with 132;
select add_amenity(52, 'camp-esport', 'Camp Esport', '<p>Lorem ipsum dolor sit amet, consectetur adipiscing elit. Donec scelerisque lorem vestibulum enim sollicitudin ornare. Aliquam egestas pretium porttitor. Donec iaculis tempus est, id lobortis risus semper vel. Maecenas ut imperdiet neque. Donec mattis purus felis, vitae interdum risus egestas pharetra. Vestibulum dui neque, condimentum ultrices erat sed, fringilla pharetra ante. Maecenas hendrerit neque mattis risus consectetur euismod. Cras urna metus, bibendum a neque sed, pharetra commodo magna.</p>', '<p>Lorem ipsum dolor sit amet, consectetur adipiscing elit. Donec scelerisque lorem vestibulum enim sollicitudin ornare. Aliquam egestas pretium porttitor. Donec iaculis tempus est, id lobortis risus semper vel. Maecenas ut imperdiet neque. Donec mattis purus felis, vitae interdum risus egestas pharetra. Vestibulum dui neque, condimentum ultrices erat sed, fringilla pharetra ante. Maecenas hendrerit neque mattis risus consectetur euismod. Cras urna metus, bibendum a neque sed, pharetra commodo magna.</p>'); select add_amenity(52, 'camp-esport', 'Camp Esport', '<p>Lorem ipsum dolor sit amet, consectetur adipiscing elit. Donec scelerisque lorem vestibulum enim sollicitudin ornare. Aliquam egestas pretium porttitor. Donec iaculis tempus est, id lobortis risus semper vel. Maecenas ut imperdiet neque. Donec mattis purus felis, vitae interdum risus egestas pharetra. Vestibulum dui neque, condimentum ultrices erat sed, fringilla pharetra ante. Maecenas hendrerit neque mattis risus consectetur euismod. Cras urna metus, bibendum a neque sed, pharetra commodo magna.</p>', '<p>Lorem ipsum dolor sit amet, consectetur adipiscing elit. Donec scelerisque lorem vestibulum enim sollicitudin ornare. Aliquam egestas pretium porttitor. Donec iaculis tempus est, id lobortis risus semper vel. Maecenas ut imperdiet neque. Donec mattis purus felis, vitae interdum risus egestas pharetra. Vestibulum dui neque, condimentum ultrices erat sed, fringilla pharetra ante. Maecenas hendrerit neque mattis risus consectetur euismod. Cras urna metus, bibendum a neque sed, pharetra commodo magna.</p>');

View File

@ -1,13 +0,0 @@
-- Deploy camper:booking__campsite_id to pg
-- requires: booking
begin;
set search_path to camper, public;
alter table booking
add column campsite_id integer references campsite
, add constraint booking_needs_campsite check ( booking_status in ('created', 'cancelled') or campsite_id is not null )
;
commit;

View File

@ -0,0 +1,25 @@
-- Deploy camper:booking_campsite to pg
-- requires: roles
-- requires: schema_camper
-- requires: booking
-- requires: campsite
-- requires: extension_btree_gist
begin;
set search_path to camper, public;
create table booking_campsite (
booking_id integer not null references booking,
campsite_id integer not null references campsite,
stay daterange not null,
primary key (booking_id, campsite_id, stay),
exclude using gist (campsite_id with =, stay with &&)
);
create index booking_campsite_stay_idx on booking_campsite using gist (stay);
grant select, insert, update, delete on table booking_campsite to employee;
grant select, insert, update, delete on table booking_campsite to admin;
commit;

View File

@ -139,17 +139,17 @@ func collectBookingEntries(ctx context.Context, company *auth.Company, conn *dat
lastDay := to.AddDate(0, 1, 0) lastDay := to.AddDate(0, 1, 0)
rows, err := conn.Query(ctx, ` rows, err := conn.Query(ctx, `
select campsite.label select campsite.label
, lower(stay * daterange($2::date, $3::date)) , lower(booking_campsite.stay * daterange($2::date, $3::date))
, holder_name , holder_name
, booking_status , booking_status
, upper(stay * daterange($2::date, $3::date)) - lower(stay * daterange($2::date, $3::date)) , upper(booking_campsite.stay * daterange($2::date, $3::date)) - lower(booking_campsite.stay * daterange($2::date, $3::date))
, stay &> daterange($2::date, $3::date) , booking_campsite.stay &> daterange($2::date, $3::date)
, stay &< daterange($2::date, $3::date) , booking_campsite.stay &< daterange($2::date, $3::date)
from booking from booking_campsite
join booking using (booking_id)
join campsite using (campsite_id) join campsite using (campsite_id)
where booking.company_id = $1 where booking.company_id = $1
and stay && daterange($2::date, $3::date) and booking_campsite.stay && daterange($2::date, $3::date)
and booking_status <> 'cancelled'
order by label`, company.ID, from, lastDay) order by label`, company.ID, from, lastDay)
if err != nil { if err != nil {
return err return err

View File

@ -1,9 +0,0 @@
-- Revert camper:booking__campsite_id from pg
begin;
alter table camper.booking
drop column if exists campsite_id
;
commit;

View File

@ -0,0 +1,7 @@
-- Revert camper:booking_campsite from pg
begin;
drop table if exists camper.booking_campsite;
commit;

View File

@ -282,4 +282,4 @@ draft_payment [draft_payment@v6] 2024-03-20T17:11:41Z jordi fita mas <jordi@tand
acsi_option__option_group [acsi_option] 2024-04-03T07:55:37Z jordi fita mas <jordi@tandem.blog> # Add option_group column to acsi_option acsi_option__option_group [acsi_option] 2024-04-03T07:55:37Z jordi fita mas <jordi@tandem.blog> # Add option_group column to acsi_option
draft_payment [draft_payment@v7 acsi_option__option_group] 2024-04-03T08:15:40Z jordi fita mas <jordi@tandem.blog> # Take option_group in account when discounting ACSI options in draft_payment draft_payment [draft_payment@v7 acsi_option__option_group] 2024-04-03T08:15:40Z jordi fita mas <jordi@tandem.blog> # Take option_group in account when discounting ACSI options in draft_payment
booking__stay [booking] 2024-04-19T16:02:11Z jordi fita mas <jordi@tandem.blog> # Replace booking arrival and departure dates with a daterange booking__stay [booking] 2024-04-19T16:02:11Z jordi fita mas <jordi@tandem.blog> # Replace booking arrival and departure dates with a daterange
booking__campsite_id [booking] 2024-04-19T17:58:25Z jordi fita mas <jordi@tandem.blog> # Add campsite_id to booking booking_campsite [roles schema_camper booking campsite extension_btree_gist] 2024-04-21T18:27:20Z jordi fita mas <jordi@tandem.blog> # Add relation of campsite booking

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(84); select plan(78);
set search_path to camper, public; set search_path to camper, public;
@ -43,13 +43,6 @@ select col_type_is('booking', 'campsite_type_id', 'integer');
select col_not_null('booking', 'campsite_type_id'); select col_not_null('booking', 'campsite_type_id');
select col_hasnt_default('booking', 'campsite_type_id'); select col_hasnt_default('booking', 'campsite_type_id');
select has_column('booking', 'campsite_id');
select col_is_fk('booking', 'campsite_id');
select fk_ok('booking', 'campsite_id', 'campsite', 'campsite_id');
select col_type_is('booking', 'campsite_id', 'integer');
select col_is_null('booking', 'campsite_id');
select col_hasnt_default('booking', 'campsite_id');
select has_column('booking', 'holder_name'); select has_column('booking', 'holder_name');
select col_type_is('booking', 'holder_name', 'text'); select col_type_is('booking', 'holder_name', 'text');
select col_not_null('booking', 'holder_name'); select col_not_null('booking', 'holder_name');

94
test/booking_campsite.sql Normal file
View File

@ -0,0 +1,94 @@
-- Test booking_campsite
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(25);
set search_path to camper, public;
select has_table('booking_campsite');
select has_pk('booking_campsite');
select col_is_pk('booking_campsite', array['booking_id', 'campsite_id', 'stay']);
select table_privs_are('booking_campsite', 'guest', array[]::text[]);
select table_privs_are('booking_campsite', 'employee', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('booking_campsite', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('booking_campsite', 'authenticator', array[]::text[]);
select has_column('booking_campsite', 'booking_id');
select col_is_fk('booking_campsite', 'booking_id');
select fk_ok('booking_campsite', 'booking_id', 'booking', 'booking_id');
select col_type_is('booking_campsite', 'booking_id', 'integer');
select col_not_null('booking_campsite', 'booking_id');
select col_hasnt_default('booking_campsite', 'booking_id');
select has_column('booking_campsite', 'campsite_id');
select col_is_fk('booking_campsite', 'campsite_id');
select fk_ok('booking_campsite', 'campsite_id', 'campsite', 'campsite_id');
select col_type_is('booking_campsite', 'campsite_id', 'integer');
select col_not_null('booking_campsite', 'campsite_id');
select col_hasnt_default('booking_campsite', 'campsite_id');
select has_column('booking_campsite', 'stay');
select col_type_is('booking_campsite', 'stay', 'daterange');
select col_not_null('booking_campsite', 'stay');
select col_hasnt_default('booking_campsite', 'stay');
set client_min_messages to warning;
truncate booking_campsite cascade;
truncate booking cascade;
truncate campsite_type cascade;
truncate media cascade;
truncate media_content cascade;
truncate company cascade;
reset client_min_messages;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, rtc_number, tourist_tax, tourist_tax_max_days, country_code, currency_code, default_lang_tag)
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', '', 60, 7, 'ES', 'EUR', 'ca')
;
insert into media_content (media_type, bytes)
values ('image/x-xpixmap', 'static char *s[]={"1 1 1 1","a c #ffffff","a"};')
;
insert into media (media_id, company_id, original_filename, content_hash)
values (6, 2, 'cover2.xpm', sha256('static char *s[]={"1 1 1 1","a c #ffffff","a"};'))
;
insert into campsite_type (campsite_type_id, company_id, name, media_id, max_campers, bookable_nights)
values (10, 2, 'Wooden lodge', 6, 7, '[1, 7]')
;
insert into campsite (campsite_id, company_id, label, campsite_type_id)
values (12, 2, 'A', 10)
, (14, 2, 'B', 10)
, (16, 2, 'C', 10)
;
insert into booking (booking_id, company_id, campsite_type_id, holder_name, stay, number_dogs, acsi_card)
values (18, 2, 10, 'Holder 2', daterange('2024-01-18', '2024-01-29'), 0, false)
, (20, 2, 10, 'Holder 4', daterange('2024-01-28', '2024-01-29'), 0, false)
;
insert into booking_campsite (booking_id, campsite_id, stay)
values (18, 12, daterange('2024-01-18', '2024-01-29'))
;
select lives_ok(
$$ insert into booking_campsite (booking_id, campsite_id, stay) values (18, 16, daterange('2024-01-19', '2024-01-29')) $$,
'Can insert a new campsite booking for the same range as another.'
);
select throws_ok(
$$ insert into booking_campsite (booking_id, campsite_id, stay) values (20, 14, daterange('2024-01-28', '2024-01-29')) $$,
'23P01', 'conflicting key value violates exclusion constraint "booking_campsite_campsite_id_stay_excl"',
'Can not insert a new booking for the same campsite if the dates overlap.'
);
select *
from finish();
rollback;

View File

@ -1,10 +0,0 @@
-- Verify camper:booking__campsite_id on pg
begin;
select campsite_id
from camper.booking
where false
;
rollback;

View File

@ -0,0 +1,11 @@
-- Verify camper:booking_campsite on pg
begin;
select booking_id
, campsite_id
, stay
from camper.booking_campsite
where false;
rollback;