numerus/deploy/invoice.sql
jordi fita mas bc48dd4089 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 21:31:35 +02:00

50 lines
1.4 KiB
PL/PgSQL

-- Deploy numerus:invoice to pg
-- requires: schema_numerus
-- requires: company
-- requires: contact
-- requires: invoice_status
-- requires: currency
-- requires: tag_name
begin;
set search_path to numerus, public;
create table invoice (
invoice_id serial primary key,
company_id integer not null references company,
slug uuid not null unique default gen_random_uuid(),
invoice_number text not null constraint invoice_number_not_empty check(length(trim(invoice_number)) > 1),
invoice_date date not null default current_date,
contact_id integer not null references contact,
invoice_status text not null default 'created' references invoice_status,
notes text not null default '',
tags tag_name[] not null default '{}',
payment_method_id integer not null references payment_method,
currency_code text not null references currency,
created_at timestamptz not null default current_timestamp
);
create index on invoice using gin (tags);
grant select, insert, update, delete on table invoice to invoicer;
grant select, insert, update, delete on table invoice to admin;
grant usage on sequence invoice_invoice_id_seq to invoicer;
grant usage on sequence invoice_invoice_id_seq to admin;
alter table invoice enable row level security;
create policy company_policy
on invoice
using (
exists(
select 1
from company_user
join user_profile using (user_id)
where company_user.company_id = invoice.company_id
)
);
commit;