camper/deploy/campsite_type.sql

62 lines
1.4 KiB
MySQL
Raw Normal View History

-- Deploy camper:campsite_type to pg
-- requires: roles
-- requires: schema_camper
-- requires: company
-- requires: user_profile
Add cover media to campsite types This is the image that is shown at the home page, and maybe other pages in the future. We can not use a static file because this image can be changed by the customer, not us; just like name and description. I decided to keep the actual media content in the database, but to copy this file out to the file system the first time it is accessed. This is because we are going to replicate the database to a public instance that must show exactly the same image, but the customer will update the image from the private instance, behind a firewall. We could also synchronize the folder where they upload the images, the same way we will replicate, but i thought that i would make the whole thing a little more brittle: this way if it can replicate the update of the media, it is impossible to not have its contents; dumping it to a file is to improve subsequent requests to the same media. I use the hex representation of the media’s hash as the URL to the resource, because PostgreSQL’s base64 is not URL save (i.e., it uses RFC2045’s charset that includes the forward slash[0]), and i did not feel necessary write a new function just to slightly reduce the URLs’ length. Before checking if the file exists, i make sure that the given hash is an hex string, like i do for UUID, otherwise any other check is going to fail for sure. I moved out hex.Valid function from UUID to check for valid hex values, but the actual hash check is inside app/media because i doubt it will be used outside that module. [0]: https://datatracker.ietf.org/doc/html/rfc2045#section-6.8
2023-09-10 01:04:18 +00:00
-- requires: media
begin;
set search_path to camper, public;
create table campsite_type (
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_type_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(),
name text not null constraint name_not_empty check(length(trim(name)) > 0),
Add cover media to campsite types This is the image that is shown at the home page, and maybe other pages in the future. We can not use a static file because this image can be changed by the customer, not us; just like name and description. I decided to keep the actual media content in the database, but to copy this file out to the file system the first time it is accessed. This is because we are going to replicate the database to a public instance that must show exactly the same image, but the customer will update the image from the private instance, behind a firewall. We could also synchronize the folder where they upload the images, the same way we will replicate, but i thought that i would make the whole thing a little more brittle: this way if it can replicate the update of the media, it is impossible to not have its contents; dumping it to a file is to improve subsequent requests to the same media. I use the hex representation of the media’s hash as the URL to the resource, because PostgreSQL’s base64 is not URL save (i.e., it uses RFC2045’s charset that includes the forward slash[0]), and i did not feel necessary write a new function just to slightly reduce the URLs’ length. Before checking if the file exists, i make sure that the given hash is an hex string, like i do for UUID, otherwise any other check is going to fail for sure. I moved out hex.Valid function from UUID to check for valid hex values, but the actual hash check is inside app/media because i doubt it will be used outside that module. [0]: https://datatracker.ietf.org/doc/html/rfc2045#section-6.8
2023-09-10 01:04:18 +00:00
media_id integer not null references media,
description xml not null default ''::xml,
max_campers integer not null constraint at_least_one_camper check(max_campers > 0),
dogs_allowed boolean not null,
active boolean not null default true
);
grant select on table campsite_type to guest;
grant select on table campsite_type to employee;
grant select, insert, update, delete on table campsite_type to admin;
alter table campsite_type enable row level security;
create policy guest_ok
on campsite_type
for select
using (true)
;
create policy insert_to_company
on campsite_type
for insert
with check (
company_id in (select company_id from user_profile)
)
;
create policy update_company
on campsite_type
for update
using (
company_id in (select company_id from user_profile)
)
;
create policy delete_from_company
on campsite_type
for delete
using (
company_id in (select company_id from user_profile)
)
;
commit;