2023-08-14 18:18:26 +00:00
|
|
|
-- Deploy camper:campsite to pg
|
|
|
|
-- requires: roles
|
|
|
|
-- requires: schema_camper
|
|
|
|
-- requires: company
|
|
|
|
-- requires: campsite_type
|
|
|
|
-- requires: user_profile
|
|
|
|
|
|
|
|
begin;
|
|
|
|
|
|
|
|
set search_path to camper, public;
|
|
|
|
|
|
|
|
create table campsite (
|
Replace serial columns with ‘generated by default as identity’
I just found out that this is a feature introduced in PostgreSQL 10,
back in 2017.
Besides this being the standard way to define an “auto incremental
column” introduced in SQL:2003[0], called “identity columns”, in
PostgreSQL the new syntax has the following pros, according to [1]:
* No need to explicitly grant usage on the generated sequence.
* Can restart the sequence with only the name of the table and column;
no need to know the sequence’s name.
* An identity column has no default, and the sequence is better
“linked” to the table, therefore you can not drop the default value
but leave the sequence around, and, conversely, can not drop the
sequence if the column is still defined.
Due to this, PostgreSQL’s authors recommendation is to use identity
columns instead of serial, unless there is the need for compatibility
with PostgreSQL older than 10[2], which is not our case.
According to PostgreSQL’s documentation[3], the identity column can be
‘GENERATED BY DEFAULT’ or ‘GENERATED ALWAYS’. In the latter case, it is
not possible to give a user-specified value when inserting unless
specifying ‘OVERRIDING SYSTEM VALUE’. I think this would make harder to
write pgTAP tests, and the old behaviour of serial, which is equivalent
to ‘GENERATED BY DEFAULT’, did not bring me any trouble so far.
[0]: https://sigmodrecord.org/publications/sigmodRecord/0403/E.JimAndrew-standard.pdf
[1]: https://www.2ndquadrant.com/en/blog/postgresql-10-identity-columns/
[2]: https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial
[3]: https://www.postgresql.org/docs/15/sql-createtable.html
2023-09-26 17:35:16 +00:00
|
|
|
campsite_id integer generated by default as identity primary key,
|
2023-08-14 18:18:26 +00:00
|
|
|
company_id integer not null references company,
|
|
|
|
label text not null constraint label_not_empty check(length(trim(label)) > 0),
|
Add campsite map in SVG
I intend to use the same SVG file for customers and employees, so i had
to change Oriol’s design to add a class to layers that are supposed to
be only for customers, like trees. These are hidden in the admin area.
I understood that customers and employees have to click on a campsite to
select it, and then they can book or whatever they need to do to them.
Since customers and employees most certainly will need to have different
listeners on campsites, i decided to add the link with JavaScript. To
do so, i need a custom XML attribute with the campsite’s identifier.
Since i have seen that all campsites have a label, i changed the
“identifier” to the unique combination (company_id, label). The
company_id is there because different companies could have the same
label; i left the campsite_id primary key for foreign constraints.
In this case, as a test, i add an <a> element to the campsite with a
link to edit it; we’ll discuss with Oriol what exactly it needs to do.
However, the original design had the labels in a different layer, that
interfered with the link, as the numbers must be above the path and
the link must wrap the path in order to “inherit” its shape. I had no
other recourse than to move the labels in the same layer as the paths’.
2023-09-24 01:17:13 +00:00
|
|
|
campsite_type_id integer not null references campsite_type,
|
|
|
|
active boolean not null default true,
|
|
|
|
unique (company_id, label)
|
2023-08-14 18:18:26 +00:00
|
|
|
);
|
|
|
|
|
|
|
|
grant select on table campsite to guest;
|
|
|
|
grant select on table campsite to employee;
|
|
|
|
grant select, insert, update, delete on table campsite to admin;
|
|
|
|
|
|
|
|
alter table campsite enable row level security;
|
|
|
|
|
|
|
|
create policy guest_ok
|
|
|
|
on campsite
|
|
|
|
for select
|
|
|
|
using (true)
|
|
|
|
;
|
|
|
|
|
|
|
|
create policy insert_to_company
|
|
|
|
on campsite
|
|
|
|
for insert
|
|
|
|
with check (
|
|
|
|
company_id in (select company_id from user_profile)
|
|
|
|
)
|
|
|
|
;
|
|
|
|
|
|
|
|
create policy update_company
|
|
|
|
on campsite
|
|
|
|
for update
|
|
|
|
using (
|
|
|
|
company_id in (select company_id from user_profile)
|
|
|
|
)
|
|
|
|
;
|
|
|
|
|
|
|
|
create policy delete_from_company
|
|
|
|
on campsite
|
|
|
|
for delete
|
|
|
|
using (
|
|
|
|
company_id in (select company_id from user_profile)
|
|
|
|
)
|
|
|
|
;
|
|
|
|
|
|
|
|
commit;
|