41 lines
2.1 KiB
MySQL
41 lines
2.1 KiB
MySQL
|
-- Deploy camper:payment to pg
|
||
|
-- requires: roles
|
||
|
-- requires: schema_camper
|
||
|
-- requires: company
|
||
|
-- requires: campsite_type
|
||
|
-- requires: payment_status
|
||
|
|
||
|
begin;
|
||
|
|
||
|
set search_path to camper, public;
|
||
|
|
||
|
create table payment (
|
||
|
payment_id integer generated by default as identity primary key,
|
||
|
company_id integer not null references company,
|
||
|
slug uuid not null unique default gen_random_uuid(),
|
||
|
campsite_type_id integer not null references campsite_type,
|
||
|
arrival_date date not null,
|
||
|
departure_date date not null constraint departure_after_arrival check (departure_date > arrival_date),
|
||
|
subtotal_nights integer not null constraint subtotal_nights_not_negative check (subtotal_nights >= 0),
|
||
|
number_adults integer not null constraint number_adults_positive check (number_adults > 0),
|
||
|
subtotal_adults integer not null constraint subtotal_adults_not_negative check (subtotal_adults >= 0),
|
||
|
number_teenagers integer not null constraint number_teenagers_not_negative check (number_teenagers >= 0),
|
||
|
subtotal_teenagers integer not null constraint subtotal_teenagers_not_negative check (subtotal_teenagers >= 0),
|
||
|
number_children integer not null constraint number_children_not_negative check (number_children >= 0),
|
||
|
subtotal_children integer not null constraint subtotal_children_not_negative check (subtotal_children >= 0),
|
||
|
number_dogs integer not null constraint number_dogs_not_negative check (number_dogs >= 0),
|
||
|
subtotal_dogs integer not null constraint subtotal_dogs_not_negative check (subtotal_dogs >= 0),
|
||
|
subtotal_tourist_tax integer not null constraint subtotal_tourist_tax_not_negative check (subtotal_tourist_tax >= 0),
|
||
|
total integer not null constraint total_not_negative check (total >= 0),
|
||
|
zone_preferences text not null,
|
||
|
payment_status text not null default 'draft' references payment_status,
|
||
|
created_at timestamp with time zone not null default current_timestamp,
|
||
|
updated_at timestamp with time zone not null default current_timestamp
|
||
|
);
|
||
|
|
||
|
grant select, insert, update on table payment to guest;
|
||
|
grant select, insert, update on table payment to employee;
|
||
|
grant select, insert, update, delete on table payment to admin;
|
||
|
|
||
|
commit;
|