From 3768dd5082d38dc72cd977c41faa3f3612ec3e8f Mon Sep 17 00:00:00 2001 From: jordi fita mas Date: Tue, 26 Sep 2023 19:35:16 +0200 Subject: [PATCH] =?UTF-8?q?Replace=20serial=20columns=20with=20=E2=80=98ge?= =?UTF-8?q?nerated=20by=20default=20as=20identity=E2=80=99?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit 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 --- demo/demo.sql | 14 +++++++------- deploy/campsite.sql | 4 +--- deploy/campsite_type.sql | 4 +--- deploy/company.sql | 2 +- deploy/login_attempt.sql | 2 +- deploy/media.sql | 4 +--- deploy/season.sql | 4 +--- deploy/service.sql | 4 +--- deploy/user.sql | 2 +- test/campsite.sql | 11 ++--------- test/campsite_type.sql | 11 ++--------- test/company.sql | 11 ++--------- test/login_attempt.sql | 11 ++--------- test/media.sql | 11 ++--------- test/season.sql | 11 ++--------- test/service.sql | 11 ++--------- test/user.sql | 11 ++--------- 17 files changed, 31 insertions(+), 97 deletions(-) diff --git a/demo/demo.sql b/demo/demo.sql index b6d371f..5733bfb 100644 --- a/demo/demo.sql +++ b/demo/demo.sql @@ -3,13 +3,13 @@ begin; set search_path to camper, auth, public; -alter sequence user_user_id_seq restart with 42; +alter table auth."user" alter column user_id restart with 42; insert into auth."user" (email, name, password) values ('demo@camper', 'Demo User', 'demo') , ('admin@camper', 'Demo Admin', 'admin') ; -alter sequence company_company_id_seq restart with 52; +alter table company alter column company_id restart with 52; insert into company (slug, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_lang_tag, legal_disclaimer) values ('09184122-b276-4be2-9553-e4bbcbafe40d', 'Càmping les mines, S.L.U.', 'ESB17616756', 'Pescamines', parse_packed_phone_number('972 50 60 70', 'ES'), 'info@lesmines.cat', 'https://lesmines.cat/', 'C/ de l’Hort', 'Castelló d’Empúries', 'Girona', '17486', 'ES', 'EUR', 'ca', 'Càmping les mines, S.L.U. és responsable del tractament de les seves dades d’acord amb el RGPD i la LOPDGDD, i les tracta per a mantenir una relació mercantil/comercial amb vostè. Les conservarà mentre es mantingui aquesta relació i no es comunicaran a tercers. Pot exercir els drets d’accés, rectificació, portabilitat, supressió, limitació i oposició a Càmping les mines, S.L.U., amb domicili Carrer de l’Hort 71, 17486 Castelló d’Empúries o enviant un correu electrònic a info@lesmines.cat. Per a qualsevol reclamació pot acudir a agpd.es. Per a més informació pot consultar la nostra política de privacitat a lesmines.cat.'); @@ -23,7 +23,7 @@ values (52, 42, 'employee') , (52, 43, 'admin') ; -alter sequence media_media_id_seq restart with 62; +alter table media alter column media_id restart with 62; select add_media(52, 'plots.avif', 'image/avif', decode('m4_esyscmd([[base64 -w0 demo/plots.avif]])', 'base64')); select add_media(52, 'safari_tents.avif', 'image/avif', decode('m4_esyscmd([[base64 -w0 demo/safari_tents.avif]])', 'base64')); select add_media(52, 'bungalows.avif', 'image/avif', decode('m4_esyscmd([[base64 -w0 demo/bungalows.avif]])', 'base64')); @@ -81,7 +81,7 @@ values (76, 'en', 'Tent') , (63, 'es', 'Tiendas Safari') ; -alter sequence campsite_type_campsite_type_id_seq restart with 72; +alter table campsite_type alter column campsite_type_id restart with 72; insert into campsite_type (company_id, name, media_id, description) values (52, 'Parceŀles', 62, '') , (52, 'Safari Tents', 63, '') @@ -99,7 +99,7 @@ values (72, 'en', 'Plots', '') , (75, 'es', 'Cabañas de madera', '') ; -alter sequence campsite_campsite_id_seq restart with 82; +alter table campsite alter column campsite_id restart with 82; select add_campsite(72, '2'); select add_campsite(72, '3'); select add_campsite(72, '4'); @@ -183,7 +183,7 @@ select add_campsite(72, 'D2'); select add_campsite(72, 'D3'); select add_campsite(72, 'D4'); -alter sequence service_service_id_seq restart with 82; +alter table service alter column service_id restart with 82; insert into service (company_id, icon_name, name, description) values (52, 'information', 'Informació', '

A la recepció l’informarem del que pot fer des del càmping mateix o pels voltants.

') , (52, 'wifi', 'WiFi', '

Un 80 % de l’àrea del càmping disposa d’accés WiFi lliure.

') @@ -238,7 +238,7 @@ values (82, 'en', 'Information', '

At reception we will inform you of what you , (97, 'es', 'Alquiler de neveras', '

Posibilidad de alquilar neveras para estancias largas con Rent It.

') ; -alter sequence season_season_id_seq restart with 92; +alter table season alter column season_id restart with 92; select add_season(52, 'Temporada alta', '#ff926c'); select add_season(52, 'Temporada mitjana', '#ffe37f'); select add_season(52, 'Temporada baixa', '#00aa7d'); diff --git a/deploy/campsite.sql b/deploy/campsite.sql index e04f5a2..579802c 100644 --- a/deploy/campsite.sql +++ b/deploy/campsite.sql @@ -10,7 +10,7 @@ begin; set search_path to camper, public; create table campsite ( - campsite_id serial primary key, + campsite_id integer generated by default as identity primary key, company_id integer not null references company, label text not null constraint label_not_empty check(length(trim(label)) > 0), campsite_type_id integer not null references campsite_type, @@ -22,8 +22,6 @@ grant select on table campsite to guest; grant select on table campsite to employee; grant select, insert, update, delete on table campsite to admin; -grant usage on sequence campsite_campsite_id_seq to admin; - alter table campsite enable row level security; create policy guest_ok diff --git a/deploy/campsite_type.sql b/deploy/campsite_type.sql index 54674d6..7605d72 100644 --- a/deploy/campsite_type.sql +++ b/deploy/campsite_type.sql @@ -10,7 +10,7 @@ begin; set search_path to camper, public; create table campsite_type ( - campsite_type_id serial primary key, + 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), @@ -23,8 +23,6 @@ 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; -grant usage on sequence campsite_type_campsite_type_id_seq to admin; - alter table campsite_type enable row level security; create policy guest_ok diff --git a/deploy/company.sql b/deploy/company.sql index ededd1e..0350221 100644 --- a/deploy/company.sql +++ b/deploy/company.sql @@ -16,7 +16,7 @@ begin; set search_path to camper, public; create table company ( - company_id serial primary key, + company_id integer generated by default as identity primary key, slug uuid not null unique default gen_random_uuid(), business_name text not null constraint business_name_not_empty check (length(trim(business_name)) > 1), vatin vatin not null, diff --git a/deploy/login_attempt.sql b/deploy/login_attempt.sql index 80bd4f4..079810c 100644 --- a/deploy/login_attempt.sql +++ b/deploy/login_attempt.sql @@ -6,7 +6,7 @@ begin; set search_path to auth, public; create table login_attempt ( - attempt_id bigserial primary key, + attempt_id bigint generated by default as identity primary key, user_name text not null, ip_address inet, -- nullable just in case we login from outside the web application success boolean not null, diff --git a/deploy/media.sql b/deploy/media.sql index dc34838..e72d646 100644 --- a/deploy/media.sql +++ b/deploy/media.sql @@ -10,7 +10,7 @@ begin; set search_path to camper, public; create table media ( - media_id serial not null primary key, + media_id integer generated by default as identity primary key, company_id integer not null references company, content_hash bytea not null references media_content, original_filename text not null constraint original_filename_not_empty check(length(trim(original_filename)) > 0) @@ -20,8 +20,6 @@ grant select on table media to guest; grant select on table media to employee; grant select, insert, delete, update on table media to admin; -grant usage on sequence media_media_id_seq to admin; - alter table media enable row level security; create policy guest_ok diff --git a/deploy/season.sql b/deploy/season.sql index 17ede1f..346a739 100644 --- a/deploy/season.sql +++ b/deploy/season.sql @@ -9,7 +9,7 @@ begin; set search_path to camper, public; create table season ( - season_id serial primary key, + season_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), @@ -21,8 +21,6 @@ grant select on table season to guest; grant select on table season to employee; grant select, insert, delete, update on table season to admin; -grant usage on sequence season_season_id_seq to admin; - alter table season enable row level security; create policy guest_ok diff --git a/deploy/service.sql b/deploy/service.sql index 831991b..402baa9 100644 --- a/deploy/service.sql +++ b/deploy/service.sql @@ -10,7 +10,7 @@ begin; set search_path to camper, public; create table service ( - service_id serial primary key, + service_id integer generated by default as identity primary key, company_id integer not null references company, icon_name text not null references icon, name text not null constraint name_not_empty check(length(trim(name)) > 0), @@ -21,8 +21,6 @@ grant select on table service to guest; grant select on table service to employee; grant select, insert, update, delete on table service to admin; -grant usage on sequence service_service_id_seq to admin; - alter table service enable row level security; create policy guest_ok diff --git a/deploy/user.sql b/deploy/user.sql index cb31b28..afd7c23 100644 --- a/deploy/user.sql +++ b/deploy/user.sql @@ -9,7 +9,7 @@ begin; set search_path to auth, camper, public; create table "user" ( - user_id serial primary key, + user_id integer generated by default as identity primary key, email email not null unique, name text not null, password text not null check (length(password) < 512), diff --git a/test/campsite.sql b/test/campsite.sql index 6177f8f..472570f 100644 --- a/test/campsite.sql +++ b/test/campsite.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(53); +select plan(47); set search_path to camper, public; @@ -17,18 +17,11 @@ select table_privs_are('campsite', 'employee', array['SELECT']); select table_privs_are('campsite', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('campsite', 'authenticator', array[]::text[]); -select has_sequence('campsite_campsite_id_seq'); -select sequence_privs_are('campsite_campsite_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('campsite_campsite_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('campsite_campsite_id_seq', 'admin', array['USAGE']); -select sequence_privs_are('campsite_campsite_id_seq', 'authenticator', array[]::text[]); - select has_column('campsite', 'campsite_id'); select col_is_pk('campsite', 'campsite_id'); select col_type_is('campsite', 'campsite_id', 'integer'); select col_not_null('campsite', 'campsite_id'); -select col_has_default('campsite', 'campsite_id'); -select col_default_is('campsite', 'campsite_id', 'nextval(''campsite_campsite_id_seq''::regclass)'); +select col_hasnt_default('campsite', 'campsite_id'); select has_column('campsite', 'company_id'); select col_is_fk('campsite', 'company_id'); diff --git a/test/campsite_type.sql b/test/campsite_type.sql index ee11da7..1342c62 100644 --- a/test/campsite_type.sql +++ b/test/campsite_type.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(62); +select plan(56); set search_path to camper, public; @@ -16,18 +16,11 @@ select table_privs_are('campsite_type', 'employee', array['SELECT']); select table_privs_are('campsite_type', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('campsite_type', 'authenticator', array[]::text[]); -select has_sequence('campsite_type_campsite_type_id_seq'); -select sequence_privs_are('campsite_type_campsite_type_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('campsite_type_campsite_type_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('campsite_type_campsite_type_id_seq', 'admin', array['USAGE']); -select sequence_privs_are('campsite_type_campsite_type_id_seq', 'authenticator', array[]::text[]); - select has_column('campsite_type', 'campsite_type_id'); select col_is_pk('campsite_type', 'campsite_type_id'); select col_type_is('campsite_type', 'campsite_type_id', 'integer'); select col_not_null('campsite_type', 'campsite_type_id'); -select col_has_default('campsite_type', 'campsite_type_id'); -select col_default_is('campsite_type', 'campsite_type_id', 'nextval(''campsite_type_campsite_type_id_seq''::regclass)'); +select col_hasnt_default('campsite_type', 'campsite_type_id'); select has_column('campsite_type', 'company_id'); select col_is_fk('campsite_type', 'company_id'); diff --git a/test/company.sql b/test/company.sql index f7dfe2a..d5d00f6 100644 --- a/test/company.sql +++ b/test/company.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(102); +select plan(96); set search_path to camper, public; @@ -16,18 +16,11 @@ select table_privs_are('company', 'employee', array ['SELECT']); select table_privs_are('company', 'admin', array ['SELECT', 'UPDATE']); select table_privs_are('company', 'authenticator', array []::text[]); -select has_sequence('company_company_id_seq'); -select sequence_privs_are('company_company_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('company_company_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('company_company_id_seq', 'admin', array[]::text[]); -select sequence_privs_are('company_company_id_seq', 'authenticator', array[]::text[]); - select has_column('company', 'company_id'); select col_is_pk('company', 'company_id'); select col_type_is('company', 'company_id', 'integer'); select col_not_null('company', 'company_id'); -select col_has_default('company', 'company_id'); -select col_default_is('company', 'company_id', 'nextval(''company_company_id_seq''::regclass)'); +select col_hasnt_default('company', 'company_id'); select has_column('company', 'slug'); select col_is_unique('company', 'slug'); diff --git a/test/login_attempt.sql b/test/login_attempt.sql index b92d16e..abe7520 100644 --- a/test/login_attempt.sql +++ b/test/login_attempt.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(34); +select plan(28); set search_path to auth, public; @@ -16,18 +16,11 @@ select table_privs_are('login_attempt', 'employee', array []::text[]); select table_privs_are('login_attempt', 'admin', array []::text[]); select table_privs_are('login_attempt', 'authenticator', array []::text[]); -select has_sequence('login_attempt_attempt_id_seq'); -select sequence_privs_are('login_attempt_attempt_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('login_attempt_attempt_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('login_attempt_attempt_id_seq', 'admin', array[]::text[]); -select sequence_privs_are('login_attempt_attempt_id_seq', 'authenticator', array[]::text[]); - select has_column('login_attempt', 'attempt_id'); select col_is_pk('login_attempt', 'attempt_id'); select col_type_is('login_attempt', 'attempt_id', 'bigint'); select col_not_null('login_attempt', 'attempt_id'); -select col_has_default('login_attempt', 'attempt_id'); -select col_default_is('login_attempt', 'attempt_id', 'nextval(''login_attempt_attempt_id_seq''::regclass)'); +select col_hasnt_default('login_attempt', 'attempt_id'); select has_column('login_attempt', 'user_name'); select col_type_is('login_attempt', 'user_name', 'text'); diff --git a/test/media.sql b/test/media.sql index 91c38c1..3446449 100644 --- a/test/media.sql +++ b/test/media.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(47); +select plan(41); set search_path to camper, public; @@ -16,18 +16,11 @@ select table_privs_are('media', 'employee', array['SELECT']); select table_privs_are('media', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('media', 'authenticator', array[]::text[]); -select has_sequence('media_media_id_seq'); -select sequence_privs_are('media_media_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('media_media_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('media_media_id_seq', 'admin', array['USAGE']); -select sequence_privs_are('media_media_id_seq', 'authenticator', array[]::text[]); - select has_column('media', 'media_id'); select col_is_pk('media', 'media_id'); select col_type_is('media', 'media_id', 'integer'); select col_not_null('media', 'media_id'); -select col_has_default('media', 'media_id'); -select col_default_is('media', 'media_id', 'nextval(''media_media_id_seq''::regclass)'); +select col_hasnt_default('media', 'media_id'); select has_column('media', 'company_id'); select col_is_fk('media', 'company_id'); diff --git a/test/season.sql b/test/season.sql index 7275cde..1ddfd10 100644 --- a/test/season.sql +++ b/test/season.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(57); +select plan(51); set search_path to camper, public; @@ -16,18 +16,11 @@ select table_privs_are('season', 'employee', array['SELECT']); select table_privs_are('season', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('season', 'authenticator', array[]::text[]); -select has_sequence('season_season_id_seq'); -select sequence_privs_are('season_season_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('season_season_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('season_season_id_seq', 'admin', array['USAGE']); -select sequence_privs_are('season_season_id_seq', 'authenticator', array[]::text[]); - select has_column('season', 'season_id'); select col_is_pk('season', 'season_id'); select col_type_is('season', 'season_id', 'integer'); select col_not_null('season', 'season_id'); -select col_has_default('season', 'season_id'); -select col_default_is('season', 'season_id', 'nextval(''season_season_id_seq''::regclass)'); +select col_hasnt_default('season', 'season_id'); select has_column('season', 'company_id'); select col_is_fk('season', 'company_id'); diff --git a/test/service.sql b/test/service.sql index f109113..ceaa00d 100644 --- a/test/service.sql +++ b/test/service.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(51); +select plan(45); set search_path to camper, public; @@ -16,18 +16,11 @@ select table_privs_are('service', 'employee', array['SELECT']); select table_privs_are('service', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('service', 'authenticator', array[]::text[]); -select has_sequence('service_service_id_seq'); -select sequence_privs_are('service_service_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('service_service_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('service_service_id_seq', 'admin', array['USAGE']); -select sequence_privs_are('service_service_id_seq', 'authenticator', array[]::text[]); - select has_column('service', 'service_id'); select col_is_pk('service', 'service_id'); select col_type_is('service', 'service_id', 'integer'); select col_not_null('service', 'service_id'); -select col_has_default('service', 'service_id'); -select col_default_is('service', 'service_id', 'nextval(''service_service_id_seq''::regclass)'); +select col_hasnt_default('service', 'service_id'); select has_column('service', 'company_id'); select col_is_fk('service', 'company_id'); diff --git a/test/user.sql b/test/user.sql index f95472c..3c2feb3 100644 --- a/test/user.sql +++ b/test/user.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(52); +select plan(46); set search_path to auth, public; @@ -16,18 +16,11 @@ select table_privs_are('user', 'employee', array []::text[]); select table_privs_are('user', 'admin', array []::text[]); select table_privs_are('user', 'authenticator', array []::text[]); -select has_sequence('user_user_id_seq'); -select sequence_privs_are('user_user_id_seq', 'guest', array[]::text[]); -select sequence_privs_are('user_user_id_seq', 'employee', array[]::text[]); -select sequence_privs_are('user_user_id_seq', 'admin', array[]::text[]); -select sequence_privs_are('user_user_id_seq', 'authenticator', array[]::text[]); - select has_column('user', 'user_id'); select col_is_pk('user', 'user_id'); select col_type_is('user', 'user_id', 'integer'); select col_not_null('user', 'user_id'); -select col_has_default('user', 'user_id'); -select col_default_is('user', 'user_id', 'nextval(''user_user_id_seq''::regclass)'); +select col_hasnt_default('user', 'user_id'); select has_column('user', 'email'); select col_is_unique('user', 'email');