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?
26 lines
708 B
PL/PgSQL
26 lines
708 B
PL/PgSQL
-- 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;
|