2023-01-29 14:14:31 +00:00
|
|
|
-- Deploy numerus:contact to pg
|
|
|
|
-- requires: schema_numerus
|
|
|
|
-- requires: company
|
|
|
|
-- requires: extension_vat
|
|
|
|
-- requires: email
|
|
|
|
-- requires: extension_pg_libphonenumber
|
|
|
|
-- requires: extension_uri
|
|
|
|
-- requires: country_code
|
|
|
|
-- requires: country
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
-- requires: tag_name
|
2023-01-29 14:14:31 +00:00
|
|
|
|
|
|
|
begin;
|
|
|
|
|
|
|
|
set search_path to numerus, public;
|
|
|
|
|
|
|
|
create table contact (
|
|
|
|
contact_id serial primary key,
|
|
|
|
company_id integer not null references company,
|
|
|
|
slug uuid not null unique default gen_random_uuid(),
|
2023-02-17 11:39:32 +00:00
|
|
|
business_name text not null constraint business_name_not_empty check(length(trim(business_name)) > 1),
|
2023-01-29 14:14:31 +00:00
|
|
|
vatin vatin not null,
|
|
|
|
trade_name text not null,
|
|
|
|
phone packed_phone_number not null,
|
|
|
|
email email not null,
|
|
|
|
web uri not null,
|
|
|
|
address text not null,
|
|
|
|
city text not null,
|
|
|
|
province text not null,
|
|
|
|
postal_code text not null,
|
|
|
|
country_code country_code not null references country,
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
tags tag_name[] not null default '{}',
|
2023-01-29 14:14:31 +00:00
|
|
|
created_at timestamptz not null default current_timestamp
|
|
|
|
);
|
|
|
|
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
create index on contact using gin (tags);
|
|
|
|
|
2023-01-29 14:14:31 +00:00
|
|
|
grant select, insert, update, delete on table contact to invoicer;
|
|
|
|
grant select, insert, update, delete on table contact to admin;
|
|
|
|
|
|
|
|
grant usage on sequence contact_contact_id_seq to invoicer;
|
|
|
|
grant usage on sequence contact_contact_id_seq to admin;
|
|
|
|
|
|
|
|
alter table contact enable row level security;
|
|
|
|
|
|
|
|
create policy company_policy
|
|
|
|
on contact
|
|
|
|
using (
|
|
|
|
exists(
|
|
|
|
select 1
|
|
|
|
from company_user
|
|
|
|
join user_profile using (user_id)
|
|
|
|
where company_user.company_id = contact.company_id
|
|
|
|
)
|
|
|
|
);
|
|
|
|
|
|
|
|
commit;
|