camper/test/company.sql
jordi fita mas 3768dd5082 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 19:35:16 +02:00

208 lines
7.2 KiB
PL/PgSQL

-- Test company
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(96);
set search_path to camper, public;
select has_table('company');
select has_pk('company' );
select table_privs_are('company', 'guest', array ['SELECT']);
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_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_hasnt_default('company', 'company_id');
select has_column('company', 'slug');
select col_is_unique('company', 'slug');
select col_type_is('company', 'slug', 'uuid');
select col_not_null('company', 'slug');
select col_has_default('company', 'slug');
select col_default_is('company', 'slug', 'gen_random_uuid()');
select has_column('company', 'business_name');
select col_type_is('company', 'business_name', 'text');
select col_not_null('company', 'business_name');
select col_hasnt_default('company', 'business_name');
select has_column('company', 'vatin');
select col_type_is('company', 'vatin', 'vatin');
select col_not_null('company', 'vatin');
select col_hasnt_default('company', 'vatin');
select has_column('company', 'trade_name');
select col_type_is('company', 'trade_name', 'text');
select col_not_null('company', 'trade_name');
select col_hasnt_default('company', 'trade_name');
select has_column('company', 'phone');
select col_type_is('company', 'phone', 'packed_phone_number');
select col_not_null('company', 'phone');
select col_hasnt_default('company', 'phone');
select has_column('company', 'email');
select col_type_is('company', 'email', 'email');
select col_not_null('company', 'email');
select col_hasnt_default('company', 'email');
select has_column('company', 'web');
select col_type_is('company', 'web', 'uri');
select col_not_null('company', 'web');
select col_hasnt_default('company', 'web');
select has_column('company', 'address');
select col_type_is('company', 'address', 'text');
select col_not_null('company', 'address');
select col_hasnt_default('company', 'address');
select has_column('company', 'city');
select col_type_is('company', 'city', 'text');
select col_not_null('company', 'city');
select col_hasnt_default('company', 'city');
select has_column('company', 'province');
select col_type_is('company', 'province', 'text');
select col_not_null('company', 'province');
select col_hasnt_default('company', 'province');
select has_column('company', 'postal_code');
select col_type_is('company', 'postal_code', 'text');
select col_not_null('company', 'postal_code');
select col_hasnt_default('company', 'postal_code');
select has_column('company', 'country_code');
select col_is_fk('company', 'country_code');
select fk_ok('company', 'country_code', 'country', 'country_code');
select col_type_is('company', 'country_code', 'country_code');
select col_not_null('company', 'country_code');
select col_hasnt_default('company', 'country_code');
select has_column('company', 'currency_code');
select col_is_fk('company', 'currency_code');
select fk_ok('company', 'currency_code', 'currency', 'currency_code');
select col_type_is('company', 'currency_code', 'currency_code');
select col_not_null('company', 'currency_code');
select col_hasnt_default('company', 'currency_code');
select has_column('company', 'default_lang_tag');
select col_is_fk('company', 'default_lang_tag');
select fk_ok('company', 'default_lang_tag', 'language', 'lang_tag');
select col_type_is('company', 'default_lang_tag', 'text');
select col_not_null('company', 'default_lang_tag');
select col_hasnt_default('company', 'default_lang_tag');
select has_column('company', 'invoice_number_format');
select col_type_is('company', 'invoice_number_format', 'text');
select col_not_null('company', 'invoice_number_format');
select col_has_default('company', 'invoice_number_format');
select col_default_is('company', 'invoice_number_format', '"FRA"YYYY0000');
select has_column('company', 'legal_disclaimer');
select col_type_is('company', 'legal_disclaimer', 'text');
select col_not_null('company', 'legal_disclaimer');
select col_has_default('company', 'legal_disclaimer');
select col_default_is('company', 'legal_disclaimer', '');
select has_column('company', 'created_at');
select col_type_is('company', 'created_at', 'timestamp with time zone');
select col_not_null('company', 'created_at');
select col_has_default('company', 'created_at');
select col_default_is('company', 'created_at', 'CURRENT_TIMESTAMP');
set client_min_messages to warning;
truncate company_host cascade;
truncate company_user cascade;
truncate company cascade;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
, (5, 'admin@tandem.blog', 'Demo', 'test', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_lang_tag)
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 'ca')
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 'es')
;
insert into company_user (company_id, user_id, role)
values (2, 1, 'admin')
, (4, 5, 'admin')
;
insert into company_host (company_id, host)
values (2, 'co2')
, (4, 'co4')
;
prepare company_data as
select company_id, business_name
from company
order by company_id;
set role guest;
select results_eq(
'company_data',
$$ values ( 2, 'Company 2' )
, ( 4, 'Company 4' )
$$,
'Everyone should be able to list all companies'
);
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog', 'co2');
select lives_ok(
$$ update company set business_name = 'Another Company 2' where company_id = 2 $$,
'Admin from company 2 should be able to update that company.'
);
select results_eq(
'company_data',
$$ values ( 2, 'Another Company 2' )
, ( 4, 'Company 4' )
$$,
'Should have updated the row.'
);
select lives_ok(
$$ update company set business_name = 'Another Company 4' where company_id = 4 $$,
'Admin from company 2 should NOT be able to update that company, but no error is raised.'
);
select results_eq(
'company_data',
$$ values ( 2, 'Another Company 2' )
, ( 4, 'Company 4' )
$$,
'Should NOT have updated anything.'
);
reset role;
select throws_ok( $$
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_lang_tag)
values (7, ' ', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 'ca')
$$,
'23514', 'new row for relation "company" violates check constraint "business_name_not_empty"',
'Should not allow companies with blank business name'
);
select *
from finish();
rollback;