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
This commit is contained in:
parent
4b4d7ad87d
commit
bc48dd4089
|
@ -41,7 +41,6 @@ values (1, 1, 'Retenció 15 %', -0.15)
|
||||||
, (1, 2, 'IVA 4 %', 0.04)
|
, (1, 2, 'IVA 4 %', 0.04)
|
||||||
;
|
;
|
||||||
|
|
||||||
alter sequence tag_tag_id_seq restart;
|
|
||||||
alter sequence contact_contact_id_seq restart;
|
alter sequence contact_contact_id_seq restart;
|
||||||
select add_contact (1, 'Melcior', '1', 'Rei Blanc', '0732621', 'melcio@reismags.cat', '', 'C/ Principal, 1', 'Shiraz', 'Fars', '1', 'IR', array['pesebre', 'mag']);
|
select add_contact (1, 'Melcior', '1', 'Rei Blanc', '0732621', 'melcio@reismags.cat', '', 'C/ Principal, 1', 'Shiraz', 'Fars', '1', 'IR', array['pesebre', 'mag']);
|
||||||
select add_contact (1, 'Gaspar', '2', 'Rei Ros', '111', 'gaspar@reismags.cat', '', 'C/ Principal, 2', 'Nova Delhi', 'Delhi', '2', 'IN', array['pesebre', 'mag']);
|
select add_contact (1, 'Gaspar', '2', 'Rei Ros', '111', 'gaspar@reismags.cat', '', 'C/ Principal, 2', 'Nova Delhi', 'Delhi', '2', 'IN', array['pesebre', 'mag']);
|
||||||
|
|
|
@ -18,13 +18,11 @@ declare
|
||||||
cid integer;
|
cid integer;
|
||||||
cslug uuid;
|
cslug uuid;
|
||||||
begin
|
begin
|
||||||
insert into contact (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
insert into contact (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, tags)
|
||||||
values (add_contact.company_id, add_contact.business_name, (add_contact.country_code || add_contact.vatin)::vatin, add_contact.trade_name, parse_packed_phone_number(add_contact.phone, add_contact.country_code), add_contact.email, add_contact.web, add_contact.address, add_contact.city, add_contact.province, add_contact.postal_code, add_contact.country_code)
|
values (add_contact.company_id, add_contact.business_name, (add_contact.country_code || add_contact.vatin)::vatin, add_contact.trade_name, parse_packed_phone_number(add_contact.phone, add_contact.country_code), add_contact.email, add_contact.web, add_contact.address, add_contact.city, add_contact.province, add_contact.postal_code, add_contact.country_code, add_contact.tags)
|
||||||
returning contact_id, slug
|
returning contact_id, slug
|
||||||
into cid, cslug;
|
into cid, cslug;
|
||||||
|
|
||||||
perform tag_contact(company_id, cid, tags);
|
|
||||||
|
|
||||||
return cslug;
|
return cslug;
|
||||||
end
|
end
|
||||||
$$
|
$$
|
||||||
|
|
|
@ -10,7 +10,6 @@
|
||||||
-- requires: invoice_product_tax
|
-- requires: invoice_product_tax
|
||||||
-- requires: next_invoice_number
|
-- requires: next_invoice_number
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: tag_invoice
|
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -25,12 +24,13 @@ declare
|
||||||
ccode text;
|
ccode text;
|
||||||
ipid integer;
|
ipid integer;
|
||||||
begin
|
begin
|
||||||
insert into invoice (company_id, invoice_number, invoice_date, contact_id, notes, currency_code, payment_method_id)
|
insert into invoice (company_id, invoice_number, invoice_date, contact_id, notes, tags, currency_code, payment_method_id)
|
||||||
select company_id
|
select company_id
|
||||||
, next_invoice_number(add_invoice.company, invoice_date)
|
, next_invoice_number(add_invoice.company, invoice_date)
|
||||||
, invoice_date
|
, invoice_date
|
||||||
, contact_id
|
, contact_id
|
||||||
, notes
|
, notes
|
||||||
|
, tags
|
||||||
, currency_code
|
, currency_code
|
||||||
, add_invoice.payment_method_id
|
, add_invoice.payment_method_id
|
||||||
from company
|
from company
|
||||||
|
@ -59,8 +59,6 @@ begin
|
||||||
join unnest(product.tax) as ptax(tax_id) using (tax_id);
|
join unnest(product.tax) as ptax(tax_id) using (tax_id);
|
||||||
end loop;
|
end loop;
|
||||||
|
|
||||||
perform tag_invoice(company, iid, tags);
|
|
||||||
|
|
||||||
return pslug;
|
return pslug;
|
||||||
end;
|
end;
|
||||||
$$
|
$$
|
||||||
|
|
|
@ -6,7 +6,6 @@
|
||||||
-- requires: company
|
-- requires: company
|
||||||
-- requires: currency
|
-- requires: currency
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: tag_product
|
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -18,8 +17,8 @@ declare
|
||||||
pid integer;
|
pid integer;
|
||||||
pslug uuid;
|
pslug uuid;
|
||||||
begin
|
begin
|
||||||
insert into product (company_id, name, description, price)
|
insert into product (company_id, name, description, price, tags)
|
||||||
select add_product.company_id, add_product.name, add_product.description, parse_price(add_product.price, decimal_digits)
|
select add_product.company_id, add_product.name, add_product.description, parse_price(add_product.price, decimal_digits), add_product.tags
|
||||||
from company
|
from company
|
||||||
join currency using (currency_code)
|
join currency using (currency_code)
|
||||||
where company.company_id = add_product.company_id
|
where company.company_id = add_product.company_id
|
||||||
|
@ -30,8 +29,6 @@ begin
|
||||||
select pid, tax_id
|
select pid, tax_id
|
||||||
from unnest(taxes) as tax(tax_id);
|
from unnest(taxes) as tax(tax_id);
|
||||||
|
|
||||||
perform tag_product(company_id, pid, tags);
|
|
||||||
|
|
||||||
return pslug;
|
return pslug;
|
||||||
end;
|
end;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
|
|
|
@ -7,6 +7,7 @@
|
||||||
-- requires: extension_uri
|
-- requires: extension_uri
|
||||||
-- requires: country_code
|
-- requires: country_code
|
||||||
-- requires: country
|
-- requires: country
|
||||||
|
-- requires: tag_name
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -27,9 +28,12 @@ create table contact (
|
||||||
province text not null,
|
province text not null,
|
||||||
postal_code text not null,
|
postal_code text not null,
|
||||||
country_code country_code not null references country,
|
country_code country_code not null references country,
|
||||||
|
tags tag_name[] not null default '{}',
|
||||||
created_at timestamptz not null default current_timestamp
|
created_at timestamptz not null default current_timestamp
|
||||||
);
|
);
|
||||||
|
|
||||||
|
create index on contact using gin (tags);
|
||||||
|
|
||||||
grant select, insert, update, delete on table contact to invoicer;
|
grant select, insert, update, delete on table contact to invoicer;
|
||||||
grant select, insert, update, delete on table contact to admin;
|
grant select, insert, update, delete on table contact to admin;
|
||||||
|
|
||||||
|
|
|
@ -1,31 +0,0 @@
|
||||||
-- Deploy numerus:contact_tag to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag
|
|
||||||
-- requires: contact
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create table contact_tag (
|
|
||||||
contact_id integer not null references contact,
|
|
||||||
tag_id integer not null references tag,
|
|
||||||
primary key (contact_id, tag_id)
|
|
||||||
);
|
|
||||||
|
|
||||||
grant select, insert, update, delete on table contact_tag to invoicer;
|
|
||||||
grant select, insert, update, delete on table contact_tag to admin;
|
|
||||||
|
|
||||||
alter table contact_tag enable row level security;
|
|
||||||
|
|
||||||
create policy company_policy
|
|
||||||
on contact_tag
|
|
||||||
using (
|
|
||||||
exists(
|
|
||||||
select 1
|
|
||||||
from contact
|
|
||||||
where contact.contact_id = contact_tag.contact_id
|
|
||||||
)
|
|
||||||
);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -5,7 +5,6 @@
|
||||||
-- requires: country_code
|
-- requires: country_code
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: contact
|
-- requires: contact
|
||||||
-- requires: tag_contact
|
|
||||||
-- requires: extension_vat
|
-- requires: extension_vat
|
||||||
-- requires: extension_pg_libphonenumber
|
-- requires: extension_pg_libphonenumber
|
||||||
|
|
||||||
|
@ -31,6 +30,7 @@ begin
|
||||||
, province = edit_contact.province
|
, province = edit_contact.province
|
||||||
, postal_code = edit_contact.postal_code
|
, postal_code = edit_contact.postal_code
|
||||||
, country_code = edit_contact.country_code
|
, country_code = edit_contact.country_code
|
||||||
|
, tags = edit_contact.tags
|
||||||
where slug = contact_slug
|
where slug = contact_slug
|
||||||
returning contact_id, company_id
|
returning contact_id, company_id
|
||||||
into cid, company
|
into cid, company
|
||||||
|
@ -40,8 +40,6 @@ begin
|
||||||
return null;
|
return null;
|
||||||
end if;
|
end if;
|
||||||
|
|
||||||
perform tag_contact(company, cid, tags);
|
|
||||||
|
|
||||||
return contact_slug;
|
return contact_slug;
|
||||||
end
|
end
|
||||||
$$
|
$$
|
||||||
|
|
|
@ -8,7 +8,6 @@
|
||||||
-- requires: invoice_product
|
-- requires: invoice_product
|
||||||
-- requires: invoice_product_tax
|
-- requires: invoice_product_tax
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: tag_invoice
|
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -30,6 +29,7 @@ begin
|
||||||
, invoice_status = edit_invoice.invoice_status
|
, invoice_status = edit_invoice.invoice_status
|
||||||
, notes = edit_invoice.notes
|
, notes = edit_invoice.notes
|
||||||
, payment_method_id = edit_invoice.payment_method_id
|
, payment_method_id = edit_invoice.payment_method_id
|
||||||
|
, tags = edit_invoice.tags
|
||||||
where slug = invoice_slug
|
where slug = invoice_slug
|
||||||
returning invoice_id, company_id, currency_code
|
returning invoice_id, company_id, currency_code
|
||||||
into iid, company, ccode
|
into iid, company, ccode
|
||||||
|
@ -89,8 +89,6 @@ begin
|
||||||
delete from invoice_product where invoice_product_id = any(products_to_delete);
|
delete from invoice_product where invoice_product_id = any(products_to_delete);
|
||||||
end if;
|
end if;
|
||||||
|
|
||||||
perform tag_invoice(company, iid, tags);
|
|
||||||
|
|
||||||
return invoice_slug;
|
return invoice_slug;
|
||||||
end;
|
end;
|
||||||
$$
|
$$
|
||||||
|
|
|
@ -6,7 +6,6 @@
|
||||||
-- requires: company
|
-- requires: company
|
||||||
-- requires: currency
|
-- requires: currency
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: tag_product
|
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -22,6 +21,7 @@ begin
|
||||||
set name = edit_product.name
|
set name = edit_product.name
|
||||||
, description = edit_product.description
|
, description = edit_product.description
|
||||||
, price = parse_price(edit_product.price, decimal_digits)
|
, price = parse_price(edit_product.price, decimal_digits)
|
||||||
|
, tags = edit_product.tags
|
||||||
from company
|
from company
|
||||||
join currency using (currency_code)
|
join currency using (currency_code)
|
||||||
where product.company_id = company.company_id
|
where product.company_id = company.company_id
|
||||||
|
@ -39,8 +39,6 @@ begin
|
||||||
select pid, tax_id
|
select pid, tax_id
|
||||||
from unnest(taxes) as tax(tax_id);
|
from unnest(taxes) as tax(tax_id);
|
||||||
|
|
||||||
perform tag_product(company, pid, tags);
|
|
||||||
|
|
||||||
return true;
|
return true;
|
||||||
end;
|
end;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
|
|
|
@ -4,6 +4,7 @@
|
||||||
-- requires: contact
|
-- requires: contact
|
||||||
-- requires: invoice_status
|
-- requires: invoice_status
|
||||||
-- requires: currency
|
-- requires: currency
|
||||||
|
-- requires: tag_name
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -18,11 +19,14 @@ create table invoice (
|
||||||
contact_id integer not null references contact,
|
contact_id integer not null references contact,
|
||||||
invoice_status text not null default 'created' references invoice_status,
|
invoice_status text not null default 'created' references invoice_status,
|
||||||
notes text not null default '',
|
notes text not null default '',
|
||||||
|
tags tag_name[] not null default '{}',
|
||||||
payment_method_id integer not null references payment_method,
|
payment_method_id integer not null references payment_method,
|
||||||
currency_code text not null references currency,
|
currency_code text not null references currency,
|
||||||
created_at timestamptz not null default current_timestamp
|
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 invoicer;
|
||||||
grant select, insert, update, delete on table invoice to admin;
|
grant select, insert, update, delete on table invoice to admin;
|
||||||
|
|
||||||
|
|
|
@ -1,31 +0,0 @@
|
||||||
-- Deploy numerus:invoice_tag to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag
|
|
||||||
-- requires: invoice
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create table invoice_tag (
|
|
||||||
invoice_id integer not null references invoice,
|
|
||||||
tag_id integer not null references tag,
|
|
||||||
primary key (invoice_id, tag_id)
|
|
||||||
);
|
|
||||||
|
|
||||||
grant select, insert, update, delete on table invoice_tag to invoicer;
|
|
||||||
grant select, insert, update, delete on table invoice_tag to admin;
|
|
||||||
|
|
||||||
alter table invoice_tag enable row level security;
|
|
||||||
|
|
||||||
create policy company_policy
|
|
||||||
on invoice_tag
|
|
||||||
using (
|
|
||||||
exists(
|
|
||||||
select 1
|
|
||||||
from invoice
|
|
||||||
where invoice.invoice_id = invoice_tag.invoice_id
|
|
||||||
)
|
|
||||||
);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -2,6 +2,7 @@
|
||||||
-- requires: schema_numerus
|
-- requires: schema_numerus
|
||||||
-- requires: company
|
-- requires: company
|
||||||
-- requires: tax
|
-- requires: tax
|
||||||
|
-- requires: tag_name
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -14,12 +15,15 @@ create table product (
|
||||||
name text not null constraint name_not_empty check(length(trim(name)) > 0),
|
name text not null constraint name_not_empty check(length(trim(name)) > 0),
|
||||||
description text not null default '',
|
description text not null default '',
|
||||||
price integer not null,
|
price integer not null,
|
||||||
|
tags tag_name[] not null default '{}',
|
||||||
created_at timestamptz not null default current_timestamp
|
created_at timestamptz not null default current_timestamp
|
||||||
);
|
);
|
||||||
|
|
||||||
comment on column product.price is
|
comment on column product.price is
|
||||||
'Price is stored in cents.';
|
'Price is stored in cents.';
|
||||||
|
|
||||||
|
create index on product using gin (tags);
|
||||||
|
|
||||||
grant select, insert, update, delete on table product to invoicer;
|
grant select, insert, update, delete on table product to invoicer;
|
||||||
grant select, insert, update, delete on table product to admin;
|
grant select, insert, update, delete on table product to admin;
|
||||||
|
|
||||||
|
|
|
@ -1,31 +0,0 @@
|
||||||
-- Deploy numerus:product_tag to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag
|
|
||||||
-- requires: product
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create table product_tag (
|
|
||||||
product_id integer not null references product,
|
|
||||||
tag_id integer not null references tag,
|
|
||||||
primary key (product_id, tag_id)
|
|
||||||
);
|
|
||||||
|
|
||||||
grant select, insert, update, delete on table product_tag to invoicer;
|
|
||||||
grant select, insert, update, delete on table product_tag to admin;
|
|
||||||
|
|
||||||
alter table product_tag enable row level security;
|
|
||||||
|
|
||||||
create policy company_policy
|
|
||||||
on product_tag
|
|
||||||
using (
|
|
||||||
exists(
|
|
||||||
select 1
|
|
||||||
from product
|
|
||||||
where product.product_id = product_tag.product_id
|
|
||||||
)
|
|
||||||
);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,35 +0,0 @@
|
||||||
-- Deploy numerus:tag to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag_name
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create table tag (
|
|
||||||
tag_id serial primary key,
|
|
||||||
company_id integer not null references company,
|
|
||||||
name tag_name not null,
|
|
||||||
unique (company_id, name)
|
|
||||||
);
|
|
||||||
|
|
||||||
grant select, insert, update, delete on table tag to invoicer;
|
|
||||||
grant select, insert, update, delete on table tag to admin;
|
|
||||||
|
|
||||||
grant usage on sequence tag_tag_id_seq to invoicer;
|
|
||||||
grant usage on sequence tag_tag_id_seq to admin;
|
|
||||||
|
|
||||||
alter table tag enable row level security;
|
|
||||||
|
|
||||||
create policy company_policy
|
|
||||||
on tag
|
|
||||||
using (
|
|
||||||
exists(
|
|
||||||
select 1
|
|
||||||
from company_user
|
|
||||||
join user_profile using (user_id)
|
|
||||||
where company_user.company_id = tag.company_id
|
|
||||||
)
|
|
||||||
);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,22 +0,0 @@
|
||||||
-- Deploy numerus:tag_contact to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag_name
|
|
||||||
-- requires: tag_relation
|
|
||||||
-- requires: contact_tag
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create or replace function tag_contact (company_id integer, contact_id integer, tags tag_name[]) returns void as
|
|
||||||
$$
|
|
||||||
select tag_relation('contact_tag', 'contact_id', company_id, contact_id, tags);
|
|
||||||
$$
|
|
||||||
language sql
|
|
||||||
;
|
|
||||||
|
|
||||||
revoke execute on function tag_contact(integer, integer, tag_name[]) from public;
|
|
||||||
grant execute on function tag_contact(integer, integer, tag_name[]) to invoicer;
|
|
||||||
grant execute on function tag_contact(integer, integer, tag_name[]) to admin;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,21 +0,0 @@
|
||||||
-- Deploy numerus:tag_invoice to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag_name
|
|
||||||
-- requires: tag_invoice
|
|
||||||
-- requires: invoice_tag
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create or replace function tag_invoice(company_id integer, invoice_id integer, tags tag_name[]) returns void as
|
|
||||||
$$
|
|
||||||
select tag_relation('invoice_tag', 'invoice_id', company_id, invoice_id, tags);
|
|
||||||
$$
|
|
||||||
language sql;
|
|
||||||
|
|
||||||
revoke execute on function tag_invoice(integer, integer, tag_name[]) from public;
|
|
||||||
grant execute on function tag_invoice(integer, integer, tag_name[]) to invoicer;
|
|
||||||
grant execute on function tag_invoice(integer, integer, tag_name[]) to admin;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,22 +0,0 @@
|
||||||
-- Deploy numerus:tag_product to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag_name
|
|
||||||
-- requires: tag_relation
|
|
||||||
-- requires: product_tag
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create or replace function tag_product (company_id integer, product_id integer, tags tag_name[]) returns void as
|
|
||||||
$$
|
|
||||||
select tag_relation('product_tag', 'product_id', company_id, product_id, tags);
|
|
||||||
$$
|
|
||||||
language sql
|
|
||||||
;
|
|
||||||
|
|
||||||
revoke execute on function tag_product(integer, integer, tag_name[]) from public;
|
|
||||||
grant execute on function tag_product(integer, integer, tag_name[]) to invoicer;
|
|
||||||
grant execute on function tag_product(integer, integer, tag_name[]) to admin;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,32 +0,0 @@
|
||||||
-- Deploy numerus:tag_relation to pg
|
|
||||||
-- requires: schema_numerus
|
|
||||||
-- requires: tag
|
|
||||||
-- requires: tag_name
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
create or replace function tag_relation(relname regclass, attname name, company integer, rowid integer, tags tag_name[]) returns void as
|
|
||||||
$$
|
|
||||||
begin
|
|
||||||
execute format('delete from %I where %I = $1', relname, attname) USING rowid;
|
|
||||||
|
|
||||||
if array_length(tags, 1) > 0 then
|
|
||||||
insert into tag (company_id, name)
|
|
||||||
select company, new_tag.name
|
|
||||||
from unnest (tags) as new_tag(name)
|
|
||||||
on conflict (company_id, name) do nothing
|
|
||||||
;
|
|
||||||
|
|
||||||
execute format('insert into %I (%I, tag_id) select $1, tag_id from tag join unnest ($2) as new_tag(name) on company_id = $3 and tag.name = new_tag.name', relname, attname) USING rowid, tags, company;
|
|
||||||
end if;
|
|
||||||
end
|
|
||||||
$$
|
|
||||||
language plpgsql;
|
|
||||||
|
|
||||||
revoke execute on function tag_relation(regclass, name, integer, integer, tag_name[]) from public;
|
|
||||||
grant execute on function tag_relation(regclass, name, integer, integer, tag_name[]) to invoicer;
|
|
||||||
grant execute on function tag_relation(regclass, name, integer, integer, tag_name[]) to admin;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -131,15 +131,9 @@ func mustCollectContactEntries(ctx context.Context, conn *Conn, company *Company
|
||||||
, business_name
|
, business_name
|
||||||
, email
|
, email
|
||||||
, phone
|
, phone
|
||||||
, array_agg(coalesce(tag.name::text, ''))
|
, tags
|
||||||
from contact
|
from contact
|
||||||
left join contact_tag using (contact_id)
|
where contact.company_id = $1 and (($2 = '') or (tags @> array[$2]::tag_name[]))
|
||||||
left join tag using(tag_id)
|
|
||||||
where contact.company_id = $1 and (($2 = '') or (tag.name = $2))
|
|
||||||
group by slug
|
|
||||||
, business_name
|
|
||||||
, email
|
|
||||||
, phone
|
|
||||||
order by business_name
|
order by business_name
|
||||||
`, company.Id, tag)
|
`, company.Id, tag)
|
||||||
if err != nil {
|
if err != nil {
|
||||||
|
@ -337,22 +331,9 @@ func (form *contactForm) MustFillFromDatabase(ctx context.Context, conn *Conn, s
|
||||||
, province
|
, province
|
||||||
, postal_code
|
, postal_code
|
||||||
, country_code
|
, country_code
|
||||||
, string_agg(tag.name, ',')
|
, array_to_string(tags, ',')
|
||||||
from contact
|
from contact
|
||||||
left join contact_tag using (contact_id)
|
|
||||||
left join tag using(tag_id)
|
|
||||||
where slug = $1
|
where slug = $1
|
||||||
group by business_name
|
|
||||||
, substr(vatin::text, 3)
|
|
||||||
, trade_name
|
|
||||||
, phone
|
|
||||||
, email
|
|
||||||
, web
|
|
||||||
, address
|
|
||||||
, city
|
|
||||||
, province
|
|
||||||
, postal_code
|
|
||||||
, country_code
|
|
||||||
`, slug).Scan(
|
`, slug).Scan(
|
||||||
form.BusinessName,
|
form.BusinessName,
|
||||||
form.VATIN,
|
form.VATIN,
|
||||||
|
|
|
@ -79,33 +79,23 @@ func mustCollectInvoiceEntries(ctx context.Context, conn *Conn, company *Company
|
||||||
maybeAppendWhere("invoice_date >= $%d", filters.FromDate.String(), nil)
|
maybeAppendWhere("invoice_date >= $%d", filters.FromDate.String(), nil)
|
||||||
maybeAppendWhere("invoice_date <= $%d", filters.ToDate.String(), nil)
|
maybeAppendWhere("invoice_date <= $%d", filters.ToDate.String(), nil)
|
||||||
if len(filters.Tags.Tags) > 0 {
|
if len(filters.Tags.Tags) > 0 {
|
||||||
appendWhere("exists (select 1 from invoice_tag join tag using (tag_id) where invoice_tag.invoice_id = invoice.invoice_id and tag.name = any($%d))", filters.Tags)
|
appendWhere("invoice.tags && $%d", filters.Tags)
|
||||||
}
|
}
|
||||||
rows := conn.MustQuery(ctx, fmt.Sprintf(`
|
rows := conn.MustQuery(ctx, fmt.Sprintf(`
|
||||||
select invoice.slug
|
select invoice.slug
|
||||||
, invoice_date
|
, invoice_date
|
||||||
, invoice_number
|
, invoice_number
|
||||||
, contact.business_name
|
, contact.business_name
|
||||||
, array_agg(coalesce(tag.name::text, ''))
|
, invoice.tags
|
||||||
, invoice.invoice_status
|
, invoice.invoice_status
|
||||||
, isi18n.name
|
, isi18n.name
|
||||||
, to_price(total, decimal_digits)
|
, to_price(total, decimal_digits)
|
||||||
from invoice
|
from invoice
|
||||||
left join invoice_tag using (invoice_id)
|
|
||||||
left join tag using(tag_id)
|
|
||||||
join contact using (contact_id)
|
join contact using (contact_id)
|
||||||
join invoice_status_i18n isi18n on invoice.invoice_status = isi18n.invoice_status and isi18n.lang_tag = $1
|
join invoice_status_i18n isi18n on invoice.invoice_status = isi18n.invoice_status and isi18n.lang_tag = $1
|
||||||
join invoice_amount using (invoice_id)
|
join invoice_amount using (invoice_id)
|
||||||
join currency using (currency_code)
|
join currency using (currency_code)
|
||||||
where (%s)
|
where (%s)
|
||||||
group by invoice.slug
|
|
||||||
, invoice_date
|
|
||||||
, invoice_number
|
|
||||||
, contact.business_name
|
|
||||||
, invoice.invoice_status
|
|
||||||
, isi18n.name
|
|
||||||
, total
|
|
||||||
, decimal_digits
|
|
||||||
order by invoice_date desc
|
order by invoice_date desc
|
||||||
, invoice_number desc
|
, invoice_number desc
|
||||||
`, strings.Join(where, ") AND (")), args...)
|
`, strings.Join(where, ") AND (")), args...)
|
||||||
|
@ -673,16 +663,9 @@ func (form *invoiceForm) MustFillFromDatabase(ctx context.Context, conn *Conn, s
|
||||||
, invoice_date
|
, invoice_date
|
||||||
, notes
|
, notes
|
||||||
, payment_method_id
|
, payment_method_id
|
||||||
, string_agg(tag.name, ',')
|
, array_to_string(tags, ',')
|
||||||
from invoice
|
from invoice
|
||||||
left join invoice_tag using (invoice_id)
|
where slug = $1
|
||||||
left join tag using(tag_id) where slug = $1
|
|
||||||
group by invoice_id
|
|
||||||
, contact_id
|
|
||||||
, invoice_number
|
|
||||||
, invoice_date
|
|
||||||
, notes
|
|
||||||
, payment_method_id
|
|
||||||
`, slug).Scan(&invoiceId, form.InvoiceStatus, form.Customer, &form.Number, form.Date, form.Notes, form.PaymentMethod, form.Tags)) {
|
`, slug).Scan(&invoiceId, form.InvoiceStatus, form.Customer, &form.Number, form.Date, form.Notes, form.PaymentMethod, form.Tags)) {
|
||||||
form.PaymentMethod.Selected = selectedPaymentMethod
|
form.PaymentMethod.Selected = selectedPaymentMethod
|
||||||
form.InvoiceStatus.Selected = selectedInvoiceStatus
|
form.InvoiceStatus.Selected = selectedInvoiceStatus
|
||||||
|
|
|
@ -72,6 +72,16 @@ func registerPgTypes(ctx context.Context, conn *pgx.Conn) error {
|
||||||
if _, err := conn.Exec(ctx, "set role to admin"); err != nil {
|
if _, err := conn.Exec(ctx, "set role to admin"); err != nil {
|
||||||
return err
|
return err
|
||||||
}
|
}
|
||||||
|
tagNameOID, err := registerPgType(ctx, conn, &pgtype.Text{}, "tag_name")
|
||||||
|
if err != nil {
|
||||||
|
return err
|
||||||
|
}
|
||||||
|
tagNameArray := pgtype.NewArrayType("tag_name[]", tagNameOID, func() pgtype.ValueTranscoder {
|
||||||
|
return &pgtype.Text{}
|
||||||
|
})
|
||||||
|
if _, err := registerPgType(ctx, conn, tagNameArray, tagNameArray.TypeName()); err != nil {
|
||||||
|
return err
|
||||||
|
}
|
||||||
discountRateOID, err := registerPgType(ctx, conn, &pgtype.Numeric{}, "discount_rate")
|
discountRateOID, err := registerPgType(ctx, conn, &pgtype.Numeric{}, "discount_rate")
|
||||||
if err != nil {
|
if err != nil {
|
||||||
return err
|
return err
|
||||||
|
|
|
@ -157,16 +157,11 @@ func mustCollectProductEntries(ctx context.Context, conn *Conn, company *Company
|
||||||
select product.slug
|
select product.slug
|
||||||
, product.name
|
, product.name
|
||||||
, to_price(price, decimal_digits)
|
, to_price(price, decimal_digits)
|
||||||
, array_agg(coalesce(tag.name::text, ''))
|
, tags
|
||||||
from product
|
from product
|
||||||
join company using (company_id)
|
join company using (company_id)
|
||||||
join currency using (currency_code)
|
join currency using (currency_code)
|
||||||
left join product_tag using (product_id)
|
where product.company_id = $1 and (($2 = '') or (tags @> array[$2]::tag_name[]))
|
||||||
left join tag using(tag_id)
|
|
||||||
where product.company_id = $1 and (($2 = '') or (tag.name = $2))
|
|
||||||
group by product.slug
|
|
||||||
, product.name
|
|
||||||
, to_price(price, decimal_digits)
|
|
||||||
order by name
|
order by name
|
||||||
`, company.Id, tag)
|
`, company.Id, tag)
|
||||||
if err != nil {
|
if err != nil {
|
||||||
|
@ -267,11 +262,9 @@ func (form *productForm) MustFillFromDatabase(ctx context.Context, conn *Conn, s
|
||||||
, product.description
|
, product.description
|
||||||
, to_price(price, decimal_digits)
|
, to_price(price, decimal_digits)
|
||||||
, array_agg(tax_id)
|
, array_agg(tax_id)
|
||||||
, string_agg(tag.name, ',')
|
, array_to_string(tags, ',')
|
||||||
from product
|
from product
|
||||||
left join product_tax using (product_id)
|
left join product_tax using (product_id)
|
||||||
left join product_tag using (product_id)
|
|
||||||
left join tag using(company_id, tag_id)
|
|
||||||
join company using (company_id)
|
join company using (company_id)
|
||||||
join currency using (currency_code)
|
join currency using (currency_code)
|
||||||
where product.slug = $1
|
where product.slug = $1
|
||||||
|
@ -279,6 +272,7 @@ func (form *productForm) MustFillFromDatabase(ctx context.Context, conn *Conn, s
|
||||||
, product.name
|
, product.name
|
||||||
, product.description
|
, product.description
|
||||||
, price
|
, price
|
||||||
|
, tags
|
||||||
, decimal_digits
|
, decimal_digits
|
||||||
`, slug).Scan(
|
`, slug).Scan(
|
||||||
form.Name,
|
form.Name,
|
||||||
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:contact_tag from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop table if exists numerus.contact_tag;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:invoice_tag from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop table if exists numerus.invoice_tag;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:product_tag from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop table if exists numerus.product_tag;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:tag from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop table if exists numerus.tag;
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:tag_contact from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop function if exists numerus.tag_contact(integer, integer, numerus.tag_name[]);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:tag_invoice from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop function if exists numerus.tag_invoice(integer, integer, numerus.tag_name[]);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:tag_product from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop function if exists numerus.tag_product(integer, integer, numerus.tag_name[]);
|
|
||||||
|
|
||||||
commit;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Revert numerus:tag_relation from pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
drop function if exists numerus.tag_relation(regclass, name, integer, integer, numerus.tag_name[]);
|
|
||||||
|
|
||||||
commit;
|
|
26
sqitch.plan
26
sqitch.plan
|
@ -41,39 +41,31 @@ company_default_payment_method [schema_numerus company payment_method] 2023-03-0
|
||||||
tax_class [schema_numerus company] 2023-02-28T10:13:14Z jordi fita mas <jordi@tandem.blog> # Add the relation for tax classes
|
tax_class [schema_numerus company] 2023-02-28T10:13:14Z jordi fita mas <jordi@tandem.blog> # Add the relation for tax classes
|
||||||
tax_rate [schema_numerus] 2023-01-28T11:33:39Z jordi fita mas <jordi@tandem.blog> # Add domain for tax rates
|
tax_rate [schema_numerus] 2023-01-28T11:33:39Z jordi fita mas <jordi@tandem.blog> # Add domain for tax rates
|
||||||
tax [schema_numerus company tax_rate tax_class] 2023-01-28T11:45:47Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes
|
tax [schema_numerus company tax_rate tax_class] 2023-01-28T11:45:47Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes
|
||||||
contact [schema_numerus company extension_vat email extension_pg_libphonenumber extension_uri country_code country] 2023-01-29T12:59:18Z jordi fita mas <jordi@tandem.blog> # Add the relation for contacts
|
tag_name [schema_numerus] 2023-03-10T11:06:11Z jordi fita mas <jordi@tandem.blog> # Add domain for tag names
|
||||||
product [schema_numerus company tax] 2023-02-04T09:17:24Z jordi fita mas <jordi@tandem.blog> # Add relation for products
|
contact [schema_numerus company extension_vat email extension_pg_libphonenumber extension_uri country_code country tag_name] 2023-01-29T12:59:18Z jordi fita mas <jordi@tandem.blog> # Add the relation for contacts
|
||||||
|
product [schema_numerus company tax tag_name] 2023-02-04T09:17:24Z jordi fita mas <jordi@tandem.blog> # Add relation for products
|
||||||
parse_price [schema_public] 2023-02-05T11:04:54Z jordi fita mas <jordi@tandem.blog> # Add function to convert from price to cents
|
parse_price [schema_public] 2023-02-05T11:04:54Z jordi fita mas <jordi@tandem.blog> # Add function to convert from price to cents
|
||||||
to_price [schema_numerus] 2023-02-05T11:46:31Z jordi fita mas <jordi@tandem.blog> # Add function to format cents to prices
|
to_price [schema_numerus] 2023-02-05T11:46:31Z jordi fita mas <jordi@tandem.blog> # Add function to format cents to prices
|
||||||
invoice_status [schema_numerus] 2023-02-07T14:50:26Z jordi fita mas <jordi@tandem.blog> # A relation of invoice status
|
invoice_status [schema_numerus] 2023-02-07T14:50:26Z jordi fita mas <jordi@tandem.blog> # A relation of invoice status
|
||||||
invoice_status_i18n [schema_numerus invoice_status language] 2023-02-07T14:56:18Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice status’ translatable texts
|
invoice_status_i18n [schema_numerus invoice_status language] 2023-02-07T14:56:18Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice status’ translatable texts
|
||||||
available_invoice_status [schema_numerus invoice_status invoice_status_i18n] 2023-02-07T15:07:06Z jordi fita mas <jordi@tandem.blog> # Add the list of available invoice status
|
available_invoice_status [schema_numerus invoice_status invoice_status_i18n] 2023-02-07T15:07:06Z jordi fita mas <jordi@tandem.blog> # Add the list of available invoice status
|
||||||
product_tax [schema_numerus product tax] 2023-02-08T11:36:49Z jordi fita mas <jordi@tandem.blog> # Add relation of product taxes
|
product_tax [schema_numerus product tax] 2023-02-08T11:36:49Z jordi fita mas <jordi@tandem.blog> # Add relation of product taxes
|
||||||
invoice [schema_numerus company contact invoice_status payment_method currency] 2023-02-09T09:52:21Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice
|
invoice [schema_numerus company contact invoice_status payment_method currency tag_name] 2023-02-09T09:52:21Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice
|
||||||
discount_rate [schema_numerus] 2023-02-10T17:22:40Z jordi fita mas <jordi@tandem.blog> # Add domain for discount rates
|
discount_rate [schema_numerus] 2023-02-10T17:22:40Z jordi fita mas <jordi@tandem.blog> # Add domain for discount rates
|
||||||
invoice_product [schema_numerus invoice discount_rate] 2023-02-10T17:07:08Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice product
|
invoice_product [schema_numerus invoice discount_rate] 2023-02-10T17:07:08Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice product
|
||||||
tag_name [schema_numerus] 2023-03-10T11:06:11Z jordi fita mas <jordi@tandem.blog> # Add domain for tag names
|
add_product [schema_numerus product product_tax parse_price company currency tag_name] 2023-02-14T10:32:18Z jordi fita mas <jordi@tandem.blog> # Add function to add new products
|
||||||
tag [schema_numerus tag_name] 2023-03-10T11:04:24Z jordi fita mas <jordi@tandem.blog> # Add relation for tags
|
edit_product [schema_numerus product product_tax parse_price company currency tag_name] 2023-02-14T11:06:03Z jordi fita mas <jordi@tandem.blog> # Add function to edit products
|
||||||
tag_relation [schema_numerus tag tag_name] 2023-03-25T17:40:52Z jordi fita mas <jordi@tandem.blog> # Add function to tag “relations”
|
|
||||||
product_tag [schema_numerus tag product] 2023-03-26T10:54:23Z jordi fita mas <jordi@tandem.blog> # Add relation for product tag
|
|
||||||
tag_product [schema_numerus tag_name tag_relation product_tag] 2023-03-26T11:01:17Z jordi fita mas <jordi@tandem.blog> # Add function to tag products
|
|
||||||
add_product [schema_numerus product product_tax parse_price company currency tag_name tag_product] 2023-02-14T10:32:18Z jordi fita mas <jordi@tandem.blog> # Add function to add new products
|
|
||||||
edit_product [schema_numerus product product_tax parse_price company currency tag_name tag_product] 2023-02-14T11:06:03Z jordi fita mas <jordi@tandem.blog> # Add function to edit products
|
|
||||||
invoice_product_tax [schema_numerus invoice_product tax tax_rate] 2023-02-15T13:20:30Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes in invoice products
|
invoice_product_tax [schema_numerus invoice_product tax tax_rate] 2023-02-15T13:20:30Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes in invoice products
|
||||||
new_invoice_product [schema_numerus discount_rate] 2023-02-16T21:06:01Z jordi fita mas <jordi@tandem.blog> # Add type for passing products to new invoices
|
new_invoice_product [schema_numerus discount_rate] 2023-02-16T21:06:01Z jordi fita mas <jordi@tandem.blog> # Add type for passing products to new invoices
|
||||||
invoice_number_counter [schema_numerus company] 2023-02-17T13:04:48Z jordi fita mas <jordi@tandem.blog> # Add relation to count invoice numbers
|
invoice_number_counter [schema_numerus company] 2023-02-17T13:04:48Z jordi fita mas <jordi@tandem.blog> # Add relation to count invoice numbers
|
||||||
next_invoice_number [schema_numerus invoice_number_counter] 2023-02-17T13:21:48Z jordi fita mas <jordi@tandem.blog> # Add function to retrieve the next invoice number
|
next_invoice_number [schema_numerus invoice_number_counter] 2023-02-17T13:21:48Z jordi fita mas <jordi@tandem.blog> # Add function to retrieve the next invoice number
|
||||||
invoice_tag [schema_numerus tag invoice] 2023-03-10T11:37:43Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice tag
|
add_invoice [schema_numerus invoice company currency parse_price new_invoice_product tax invoice_product invoice_product_tax next_invoice_number tag_name] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices
|
||||||
tag_invoice [schema_numerus tag_name tag_relation invoice_tag] 2023-03-25T18:04:02Z jordi fita mas <jordi@tandem.blog> # Add function to tag invoices
|
|
||||||
add_invoice [schema_numerus invoice company currency parse_price new_invoice_product tax invoice_product invoice_product_tax next_invoice_number tag_name tag_invoice] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices
|
|
||||||
invoice_tax_amount [schema_numerus invoice_product invoice_product_tax] 2023-02-22T12:08:35Z jordi fita mas <jordi@tandem.blog> # Add view for invoice tax amount
|
invoice_tax_amount [schema_numerus invoice_product invoice_product_tax] 2023-02-22T12:08:35Z jordi fita mas <jordi@tandem.blog> # Add view for invoice tax amount
|
||||||
invoice_product_amount [schema_numerus invoice_product invoice_product_tax] 2023-03-01T11:18:05Z jordi fita mas <jordi@tandem.blog> # Add view for invoice product subtotal and total
|
invoice_product_amount [schema_numerus invoice_product invoice_product_tax] 2023-03-01T11:18:05Z jordi fita mas <jordi@tandem.blog> # Add view for invoice product subtotal and total
|
||||||
invoice_amount [schema_numerus invoice_product invoice_product_amount] 2023-02-22T12:58:46Z jordi fita mas <jordi@tandem.blog> # Add view to compute subtotal and total for invoices
|
invoice_amount [schema_numerus invoice_product invoice_product_amount] 2023-02-22T12:58:46Z jordi fita mas <jordi@tandem.blog> # Add view to compute subtotal and total for invoices
|
||||||
new_invoice_amount [schema_numerus] 2023-02-23T12:08:25Z jordi fita mas <jordi@tandem.blog> # Add type to return when computing new invoice amounts
|
new_invoice_amount [schema_numerus] 2023-02-23T12:08:25Z jordi fita mas <jordi@tandem.blog> # Add type to return when computing new invoice amounts
|
||||||
compute_new_invoice_amount [schema_numerus company currency tax new_invoice_product new_invoice_amount] 2023-02-23T12:20:13Z jordi fita mas <jordi@tandem.blog> # Add function to compute the subtotal, taxes, and total amounts for a new invoice
|
compute_new_invoice_amount [schema_numerus company currency tax new_invoice_product new_invoice_amount] 2023-02-23T12:20:13Z jordi fita mas <jordi@tandem.blog> # Add function to compute the subtotal, taxes, and total amounts for a new invoice
|
||||||
edited_invoice_product [schema_numerus discount_rate] 2023-03-11T19:22:24Z jordi fita mas <jordi@tandem.blog> # Add typo for passing products to edited invoices
|
edited_invoice_product [schema_numerus discount_rate] 2023-03-11T19:22:24Z jordi fita mas <jordi@tandem.blog> # Add typo for passing products to edited invoices
|
||||||
edit_invoice [schema_numerus invoice currency parse_price edited_invoice_product tax invoice_product invoice_product_tax tag_name tag_invoice] 2023-03-11T18:30:50Z jordi fita mas <jordi@tandem.blog> # Add function to edit invoices
|
edit_invoice [schema_numerus invoice currency parse_price edited_invoice_product tax invoice_product invoice_product_tax tag_name] 2023-03-11T18:30:50Z jordi fita mas <jordi@tandem.blog> # Add function to edit invoices
|
||||||
contact_tag [schema_numerus tag contact] 2023-03-24T22:20:51Z jordi fita mas <jordi@tandem.blog> # Add relation for contact tag
|
|
||||||
tag_contact [schema_numerus tag_name tag_relation contact_tag] 2023-03-25T22:16:42Z jordi fita mas <jordi@tandem.blog> # Add function to tag contacts
|
|
||||||
add_contact [schema_numerus extension_vat email extension_pg_libphonenumber extension_uri country_code tag_name contact] 2023-03-25T22:32:37Z jordi fita mas <jordi@tandem.blog> # Add function to create new contacts
|
add_contact [schema_numerus extension_vat email extension_pg_libphonenumber extension_uri country_code tag_name contact] 2023-03-25T22:32:37Z jordi fita mas <jordi@tandem.blog> # Add function to create new contacts
|
||||||
edit_contact [schema_numerus email extension_uri country_code tag_name contact tag_contact extension_vat extension_pg_libphonenumber] 2023-03-25T23:20:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts
|
edit_contact [schema_numerus email extension_uri country_code tag_name contact extension_vat extension_pg_libphonenumber] 2023-03-25T23:20:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(16);
|
select plan(14);
|
||||||
|
|
||||||
set search_path to auth, numerus, public;
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
@ -21,8 +21,6 @@ select function_privs_are('numerus', 'add_contact', array ['integer', 'text', 't
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate contact_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate contact cascade;
|
truncate contact cascade;
|
||||||
truncate payment_method cascade;
|
truncate payment_method cascade;
|
||||||
truncate company cascade;
|
truncate company cascade;
|
||||||
|
@ -63,34 +61,15 @@ select lives_ok(
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
select bag_eq(
|
||||||
$$ select company_id, business_name, vatin::text, trade_name, phone::text, email::text, web::text, address, city, province, postal_code, country_code::text, created_at from contact $$,
|
$$ select company_id, business_name, vatin::text, trade_name, phone::text, email::text, web::text, address, city, province, postal_code, country_code::text, tags, created_at from contact $$,
|
||||||
$$ values (1, 'Contact 2.1', 'ES40404040D', 'Trade Contact 2.1', '+34 777 77 77 77', 'c@c', 'https://c', 'Fake St., 123', 'City 2.1', 'Province 2.1', '17486', 'ES', CURRENT_TIMESTAMP)
|
$$ values (1, 'Contact 2.1', 'ES40404040D', 'Trade Contact 2.1', '+34 777 77 77 77', 'c@c', 'https://c', 'Fake St., 123', 'City 2.1', 'Province 2.1', '17486', 'ES', '{tag1,tag2}'::tag_name[], CURRENT_TIMESTAMP)
|
||||||
, (1, 'Contact 2.2', 'ES41414141L', 'Trade Contact 2.2', '+34 888 88 88 88', 'd@d', 'https://d', 'Another Fake St., 123', 'City 2.2', 'Province 2.2', '17487', 'ES', CURRENT_TIMESTAMP)
|
, (1, 'Contact 2.2', 'ES41414141L', 'Trade Contact 2.2', '+34 888 88 88 88', 'd@d', 'https://d', 'Another Fake St., 123', 'City 2.2', 'Province 2.2', '17487', 'ES', '{}'::tag_name[], CURRENT_TIMESTAMP)
|
||||||
, (2, 'Contact 4.1', 'ES42424242Y', '', '+34 999 99 99 99', 'e@e', '', 'Yet Another Fake St., 123', 'City 4.1', 'Province 4.1', '17488', 'ES', CURRENT_TIMESTAMP)
|
, (2, 'Contact 4.1', 'ES42424242Y', '', '+34 999 99 99 99', 'e@e', '', 'Yet Another Fake St., 123', 'City 4.1', 'Province 4.1', '17488', 'ES', '{tag2}'::tag_name[], CURRENT_TIMESTAMP)
|
||||||
, (1, 'Contact 2.3', 'ES43434343Q', '', '+34 000000000', 'f@f', '', 'The Last Fake St., 123', '', '', '', 'ES', CURRENT_TIMESTAMP)
|
, (1, 'Contact 2.3', 'ES43434343Q', '', '+34 000000000', 'f@f', '', 'The Last Fake St., 123', '', '', '', 'ES', '{tag2}'::tag_name[], CURRENT_TIMESTAMP)
|
||||||
$$,
|
$$,
|
||||||
'Should have created all contacts'
|
'Should have created all contacts'
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select company_id, name from tag $$,
|
|
||||||
$$ values (1, 'tag1')
|
|
||||||
, (1, 'tag2')
|
|
||||||
, (2, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have added all new tags once'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select business_name, tag.name from contact_tag join contact using (contact_id) join tag using (tag_id) $$,
|
|
||||||
$$ values ('Contact 2.1', 'tag1')
|
|
||||||
, ('Contact 2.1', 'tag2')
|
|
||||||
, ('Contact 4.1', 'tag2')
|
|
||||||
, ('Contact 2.3', 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have assigned the tags to contacts'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
select *
|
||||||
from finish();
|
from finish();
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(17);
|
select plan(15);
|
||||||
|
|
||||||
set search_path to auth, numerus, public;
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
@ -21,8 +21,6 @@ select function_privs_are('numerus', 'add_invoice', array ['integer', 'date', 'i
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate invoice_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate invoice_number_counter cascade;
|
truncate invoice_number_counter cascade;
|
||||||
truncate invoice_product_tax cascade;
|
truncate invoice_product_tax cascade;
|
||||||
truncate invoice_product cascade;
|
truncate invoice_product cascade;
|
||||||
|
@ -98,10 +96,10 @@ select lives_ok(
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
select bag_eq(
|
||||||
$$ select company_id, invoice_number, invoice_date, contact_id, invoice_status, notes, payment_method_id, currency_code, created_at from invoice $$,
|
$$ select company_id, invoice_number, invoice_date, contact_id, invoice_status, notes, payment_method_id, currency_code, tags, created_at from invoice $$,
|
||||||
$$ values (1, 'F20230006', '2023-02-15'::date, 12, 'created', 'Notes 1', 111, 'EUR', current_timestamp)
|
$$ values (1, 'F20230006', '2023-02-15'::date, 12, 'created', 'Notes 1', 111, 'EUR', '{tag1,tag2}'::tag_name[], current_timestamp)
|
||||||
, (1, 'F20230007', '2023-02-16'::date, 13, 'created', 'Notes 2', 111, 'EUR', current_timestamp)
|
, (1, 'F20230007', '2023-02-16'::date, 13, 'created', 'Notes 2', 111, 'EUR', '{}'::tag_name[], current_timestamp)
|
||||||
, (2, 'INV056-23', '2023-02-14'::date, 15, 'created', 'Notes 3', 222, 'USD', current_timestamp)
|
, (2, 'INV056-23', '2023-02-14'::date, 15, 'created', 'Notes 3', 222, 'USD', '{tag3}'::tag_name[], current_timestamp)
|
||||||
$$,
|
$$,
|
||||||
'Should have created all invoices'
|
'Should have created all invoices'
|
||||||
);
|
);
|
||||||
|
@ -126,24 +124,6 @@ select bag_eq(
|
||||||
'Should have created all invoice product taxes'
|
'Should have created all invoice product taxes'
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select company_id, name from tag $$,
|
|
||||||
$$ values (1, 'tag1')
|
|
||||||
, (1, 'tag2')
|
|
||||||
, (2, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have added all new tags once'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select invoice_number, tag.name from invoice_tag join invoice using (invoice_id) join tag using (tag_id) $$,
|
|
||||||
$$ values ('F20230006', 'tag1')
|
|
||||||
, ('F20230006', 'tag2')
|
|
||||||
, ('INV056-23', 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have assigned the tags to invoices'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
select *
|
||||||
from finish();
|
from finish();
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(16);
|
select plan(14);
|
||||||
|
|
||||||
set search_path to auth, numerus, public;
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
@ -21,8 +21,6 @@ select function_privs_are('numerus', 'add_product', array ['integer', 'text', 't
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate product_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate product_tax cascade;
|
truncate product_tax cascade;
|
||||||
truncate product cascade;
|
truncate product cascade;
|
||||||
truncate tax cascade;
|
truncate tax cascade;
|
||||||
|
@ -74,10 +72,10 @@ select lives_ok(
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
select bag_eq(
|
||||||
$$ select company_id, name, description, price, created_at from product $$,
|
$$ select company_id, name, description, price, tags, created_at from product $$,
|
||||||
$$ values (1, 'Product 1', 'Description 1', 1212, current_timestamp)
|
$$ values (1, 'Product 1', 'Description 1', 1212, '{tag1}'::tag_name[], current_timestamp)
|
||||||
, (2, 'Product 2', 'Description 2', 2424, current_timestamp)
|
, (2, 'Product 2', 'Description 2', 2424, '{tag1,tag2}'::tag_name[], current_timestamp)
|
||||||
, (2, 'Product 3', 'Description 3', 3636, current_timestamp)
|
, (2, 'Product 3', 'Description 3', 3636, '{}'::tag_name[], current_timestamp)
|
||||||
$$,
|
$$,
|
||||||
'Should have added all three products'
|
'Should have added all three products'
|
||||||
);
|
);
|
||||||
|
@ -91,24 +89,6 @@ select bag_eq(
|
||||||
'Should have added the taxes for the products we told to'
|
'Should have added the taxes for the products we told to'
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select company_id, name from tag $$,
|
|
||||||
$$ values (1, 'tag1')
|
|
||||||
, (2, 'tag1')
|
|
||||||
, (2, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have added all new tags once'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select product.name as product_name, tag.name as tag_name from product_tag join product using (product_id) join tag using (tag_id) $$,
|
|
||||||
$$ values ('Product 1', 'tag1')
|
|
||||||
, ('Product 2', 'tag1')
|
|
||||||
, ('Product 2', 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have assigned the tags to products'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
select *
|
||||||
from finish();
|
from finish();
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(85);
|
select plan(90);
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
set search_path to numerus, auth, public;
|
||||||
|
|
||||||
|
@ -100,6 +100,12 @@ select col_type_is('contact', 'country_code', 'country_code');
|
||||||
select col_not_null('contact', 'country_code');
|
select col_not_null('contact', 'country_code');
|
||||||
select col_hasnt_default('contact', 'country_code');
|
select col_hasnt_default('contact', 'country_code');
|
||||||
|
|
||||||
|
select has_column('contact', 'tags');
|
||||||
|
select col_type_is('contact', 'tags', 'tag_name[]');
|
||||||
|
select col_not_null('contact', 'tags');
|
||||||
|
select col_has_default('contact', 'tags');
|
||||||
|
select col_default_is('contact', 'tags', '{}');
|
||||||
|
|
||||||
select has_column('contact', 'created_at');
|
select has_column('contact', 'created_at');
|
||||||
select col_type_is('contact', 'created_at', 'timestamp with time zone');
|
select col_type_is('contact', 'created_at', 'timestamp with time zone');
|
||||||
select col_not_null('contact', 'created_at');
|
select col_not_null('contact', 'created_at');
|
||||||
|
|
|
@ -1,130 +0,0 @@
|
||||||
-- Test contact_tag
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(23);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_table('contact_tag');
|
|
||||||
select has_pk('contact_tag' );
|
|
||||||
select col_is_pk('contact_tag', array['contact_id', 'tag_id']);
|
|
||||||
select table_privs_are('contact_tag', 'guest', array []::text[]);
|
|
||||||
select table_privs_are('contact_tag', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('contact_tag', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('contact_tag', 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
select has_column('contact_tag', 'contact_id');
|
|
||||||
select col_is_fk('contact_tag', 'contact_id');
|
|
||||||
select fk_ok('contact_tag', 'contact_id', 'contact', 'contact_id');
|
|
||||||
select col_type_is('contact_tag', 'contact_id', 'integer');
|
|
||||||
select col_not_null('contact_tag', 'contact_id');
|
|
||||||
select col_hasnt_default('contact_tag', 'contact_id');
|
|
||||||
|
|
||||||
select has_column('contact_tag', 'tag_id');
|
|
||||||
select col_is_fk('contact_tag', 'tag_id');
|
|
||||||
select fk_ok('contact_tag', 'tag_id', 'tag', 'tag_id');
|
|
||||||
select col_type_is('contact_tag', 'tag_id', 'integer');
|
|
||||||
select col_not_null('contact_tag', 'tag_id');
|
|
||||||
select col_hasnt_default('contact_tag', 'tag_id');
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate contact_tag cascade;
|
|
||||||
truncate contact cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate contact cascade;
|
|
||||||
truncate company_user cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate auth."user" cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
|
|
||||||
values (1, 'demo@tandem.blog', 'Demo', 'test', 'invoicer', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
|
|
||||||
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 222)
|
|
||||||
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 444)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (444, 4, 'cash', 'cash')
|
|
||||||
, (222, 2, 'cash', 'cash')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into company_user (company_id, user_id)
|
|
||||||
values (2, 1)
|
|
||||||
, (4, 5)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
|
||||||
values (6, 2, 'Contact 1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
|
||||||
, (8, 4, 'Contact 2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (14, 2, 'web')
|
|
||||||
, (15, 2, 'design')
|
|
||||||
, (16, 4, 'product')
|
|
||||||
, (17, 4, 'development')
|
|
||||||
, (18, 4, 'something-else')
|
|
||||||
, (19, 4, 'design')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into contact_tag (contact_id, tag_id)
|
|
||||||
values (6, 14)
|
|
||||||
, (6, 15)
|
|
||||||
, (8, 18)
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare contact_tag_data as
|
|
||||||
select contact_id, tag_id
|
|
||||||
from contact_tag
|
|
||||||
;
|
|
||||||
|
|
||||||
set role invoicer;
|
|
||||||
select is_empty('contact_tag_data', 'Should show no data when cookie is not set yet');
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'contact_tag_data',
|
|
||||||
$$ values ( 6, 14 )
|
|
||||||
, ( 6, 15 )
|
|
||||||
$$,
|
|
||||||
'Should only list contact tags of the companies where demo@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'contact_tag_data',
|
|
||||||
$$ values ( 8, 18 )
|
|
||||||
$$,
|
|
||||||
'Should only list contact tags of the companies where admin@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('not-a-cookie');
|
|
||||||
select throws_ok(
|
|
||||||
'contact_tag_data',
|
|
||||||
'42501', 'permission denied for table contact_tag',
|
|
||||||
'Should not allow select to guest users'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(14);
|
select plan(12);
|
||||||
|
|
||||||
set search_path to auth, numerus, public;
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
@ -21,8 +21,6 @@ select function_privs_are('numerus', 'edit_contact', array ['uuid', 'text', 'tex
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate contact_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate contact cascade;
|
truncate contact cascade;
|
||||||
truncate payment_method cascade;
|
truncate payment_method cascade;
|
||||||
truncate company cascade;
|
truncate company cascade;
|
||||||
|
@ -42,22 +40,11 @@ values (111, 1, 'cash', 'cash')
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
set constraints "company_default_payment_method_id_fkey" immediate;
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
insert into contact (contact_id, company_id, slug, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, tags)
|
||||||
values (10, 1, 'tag1')
|
values (12, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Contact 1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES', '{tag1}')
|
||||||
, (11, 1, 'tag2')
|
, (13, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'Contact 2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES', '{tag2}')
|
||||||
;
|
|
||||||
-- edit_contact uses the sequence and sometimes it would confict
|
|
||||||
alter sequence tag_tag_id_seq restart with 15;
|
|
||||||
|
|
||||||
insert into contact (contact_id, company_id, slug, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
|
||||||
values (12, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Contact 1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
|
||||||
, (13, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'Contact 2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into contact_tag (contact_id, tag_id)
|
|
||||||
values (12, 10)
|
|
||||||
, (13, 11)
|
|
||||||
;
|
|
||||||
|
|
||||||
select lives_ok(
|
select lives_ok(
|
||||||
$$ select edit_contact('7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Contact 2.1', '40404040D', 'Trade Contact 2.1', '999-999-999', 'c1@c1', 'https://c', 'Fake St., 123', 'City 2.1', 'Province 2.1', '19486', 'ES', array['tag1']) $$,
|
$$ select edit_contact('7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Contact 2.1', '40404040D', 'Trade Contact 2.1', '999-999-999', 'c1@c1', 'https://c', 'Fake St., 123', 'City 2.1', 'Province 2.1', '19486', 'ES', array['tag1']) $$,
|
||||||
|
@ -70,30 +57,13 @@ select lives_ok(
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
select bag_eq(
|
||||||
$$ select company_id, business_name, vatin::text, trade_name, phone::text, email::text, web::text, address, city, province, postal_code, country_code::text, created_at from contact $$,
|
$$ select company_id, business_name, vatin::text, trade_name, phone::text, email::text, web::text, address, city, province, postal_code, country_code::text, tags, created_at from contact $$,
|
||||||
$$ values (1, 'Contact 2.1', 'ES40404040D', 'Trade Contact 2.1', '+34 999 99 99 99', 'c1@c1', 'https://c', 'Fake St., 123', 'City 2.1', 'Province 2.1', '19486', 'ES', CURRENT_TIMESTAMP)
|
$$ values (1, 'Contact 2.1', 'ES40404040D', 'Trade Contact 2.1', '+34 999 99 99 99', 'c1@c1', 'https://c', 'Fake St., 123', 'City 2.1', 'Province 2.1', '19486', 'ES', '{tag1}'::tag_name[], CURRENT_TIMESTAMP)
|
||||||
, (1, 'Contact 2.2', 'ES41414141L', 'Trade Contact 2.2', '+34 111111111', 'd2@d2', 'https://d', 'Another Fake St., 123', 'City 2.2', 'Province 2.2', '17417', 'ES', CURRENT_TIMESTAMP)
|
, (1, 'Contact 2.2', 'ES41414141L', 'Trade Contact 2.2', '+34 111111111', 'd2@d2', 'https://d', 'Another Fake St., 123', 'City 2.2', 'Province 2.2', '17417', 'ES', '{tag1,tag3}'::tag_name[], CURRENT_TIMESTAMP)
|
||||||
$$,
|
$$,
|
||||||
'Should have updated all contacts'
|
'Should have updated all contacts'
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select company_id, name from tag $$,
|
|
||||||
$$ values (1, 'tag1')
|
|
||||||
, (1, 'tag2')
|
|
||||||
, (1, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have added all new tags'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select business_name, tag.name from contact_tag join contact using (contact_id) join tag using (tag_id) $$,
|
|
||||||
$$ values ('Contact 2.1', 'tag1')
|
|
||||||
, ('Contact 2.2', 'tag1')
|
|
||||||
, ('Contact 2.2', 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have assigned the tags to contacts'
|
|
||||||
);
|
|
||||||
|
|
||||||
select *
|
select *
|
||||||
from finish();
|
from finish();
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(16);
|
select plan(14);
|
||||||
|
|
||||||
set search_path to auth, numerus, public;
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
@ -21,8 +21,6 @@ select function_privs_are('numerus', 'edit_invoice', array ['uuid', 'text', 'int
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate invoice_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate invoice_product_tax cascade;
|
truncate invoice_product_tax cascade;
|
||||||
truncate invoice_product cascade;
|
truncate invoice_product cascade;
|
||||||
truncate invoice cascade;
|
truncate invoice cascade;
|
||||||
|
@ -63,26 +61,14 @@ values ( 7, 1, 'Product 1.1', 1212)
|
||||||
, ( 9, 1, 'Product 3.3', 3636)
|
, ( 9, 1, 'Product 3.3', 3636)
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (10, 1, 'tag1')
|
|
||||||
, (11, 1, 'tag2')
|
|
||||||
;
|
|
||||||
-- edit_invoice uses the sequence and sometimes it would confict
|
|
||||||
alter sequence tag_tag_id_seq restart with 15;
|
|
||||||
|
|
||||||
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
||||||
values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
||||||
, (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
, (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into invoice (invoice_id, company_id, slug, invoice_number, invoice_date, contact_id, payment_method_id, currency_code)
|
insert into invoice (invoice_id, company_id, slug, invoice_number, invoice_date, contact_id, payment_method_id, currency_code, tags)
|
||||||
values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'INV1', '2023-03-10', 12, 111, 'EUR')
|
values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'INV1', '2023-03-10', 12, 111, 'EUR', '{tag1}')
|
||||||
, (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'INV2', '2023-03-09', 13, 111, 'EUR')
|
, (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'INV2', '2023-03-09', 13, 111, 'EUR', '{tag2}')
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice_tag (invoice_id, tag_id)
|
|
||||||
values (15, 10)
|
|
||||||
, (16, 11)
|
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into invoice_product (invoice_product_id, invoice_id, product_id, name, price)
|
insert into invoice_product (invoice_product_id, invoice_id, product_id, name, price)
|
||||||
|
@ -111,9 +97,9 @@ select lives_ok(
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
select bag_eq(
|
||||||
$$ select invoice_number, invoice_date, contact_id, invoice_status, notes, payment_method_id from invoice $$,
|
$$ select invoice_number, invoice_date, contact_id, invoice_status, notes, tags, payment_method_id from invoice $$,
|
||||||
$$ values ('INV1', '2023-03-10'::date, 13, 'paid', 'Notes 1', 112)
|
$$ values ('INV1', '2023-03-10'::date, 13, 'paid', 'Notes 1', '{tag1}'::tag_name[], 112)
|
||||||
, ('INV2', '2023-03-09'::date, 12, 'sent', 'Notes 2', 111)
|
, ('INV2', '2023-03-09'::date, 12, 'sent', 'Notes 2', '{tag1,tag3}'::tag_name[], 111)
|
||||||
$$,
|
$$,
|
||||||
'Should have updated all invoices'
|
'Should have updated all invoices'
|
||||||
);
|
);
|
||||||
|
@ -139,24 +125,6 @@ select bag_eq(
|
||||||
'Should have updated all invoice product taxes, added new ones, and removed the ones not given to the function'
|
'Should have updated all invoice product taxes, added new ones, and removed the ones not given to the function'
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select company_id, name from tag $$,
|
|
||||||
$$ values (1, 'tag1')
|
|
||||||
, (1, 'tag2')
|
|
||||||
, (1, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have added all new tags'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select invoice_number, tag.name from invoice_tag join invoice using (invoice_id) join tag using (tag_id) $$,
|
|
||||||
$$ values ('INV1', 'tag1')
|
|
||||||
, ('INV2', 'tag1')
|
|
||||||
, ('INV2', 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have assigned the tags to invoices'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
select *
|
||||||
from finish();
|
from finish();
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(17);
|
select plan(15);
|
||||||
|
|
||||||
set search_path to auth, numerus, public;
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
@ -21,8 +21,6 @@ select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'tex
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate product_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate product_tax cascade;
|
truncate product_tax cascade;
|
||||||
truncate product cascade;
|
truncate product cascade;
|
||||||
truncate tax cascade;
|
truncate tax cascade;
|
||||||
|
@ -57,10 +55,10 @@ values (3, 1, 11, 'IRPF -15 %', -0.15)
|
||||||
, (6, 2, 22, 'IVA 10 %', 0.10)
|
, (6, 2, 22, 'IVA 10 %', 0.10)
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into product (product_id, company_id, slug, name, description, price)
|
insert into product (product_id, company_id, slug, name, description, price, tags)
|
||||||
values (7, 1, 'd2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 01', 'Description01', 1200)
|
values (7, 1, 'd2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 01', 'Description01', 1200, '{tag1}')
|
||||||
, (8, 2, '2f085b8b-da90-41fe-b8cf-6ba8d94cfa38', 'Product 02', 'Description02', 2400)
|
, (8, 2, '2f085b8b-da90-41fe-b8cf-6ba8d94cfa38', 'Product 02', 'Description02', 2400, '{tag2}')
|
||||||
, (9, 2, '84044d0b-af33-442a-95a6-21efc77260d5', 'Product 03', 'Description03', 3600)
|
, (9, 2, '84044d0b-af33-442a-95a6-21efc77260d5', 'Product 03', 'Description03', 3600, '{tag2}')
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into product_tax (product_id, tax_id)
|
insert into product_tax (product_id, tax_id)
|
||||||
|
@ -70,19 +68,6 @@ values (7, 3)
|
||||||
, (9, 6)
|
, (9, 6)
|
||||||
;
|
;
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (10, 1, 'tag1')
|
|
||||||
, (11, 2, 'tag2')
|
|
||||||
;
|
|
||||||
-- edit_product uses the sequence and sometimes it would confict
|
|
||||||
alter sequence tag_tag_id_seq restart with 15;
|
|
||||||
|
|
||||||
insert into product_tag (product_id, tag_id)
|
|
||||||
values (7, 10)
|
|
||||||
, (8, 11)
|
|
||||||
, (9, 11)
|
|
||||||
;
|
|
||||||
|
|
||||||
|
|
||||||
select is(
|
select is(
|
||||||
edit_product('d2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 1', 'Description 1', '12.12', array[3, 4], array['tag1']),
|
edit_product('d2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 1', 'Description 1', '12.12', array[3, 4], array['tag1']),
|
||||||
|
@ -109,10 +94,10 @@ select is(
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
select bag_eq(
|
||||||
$$ select product_id, company_id, name, description, price from product $$,
|
$$ select product_id, company_id, name, description, price, tags from product $$,
|
||||||
$$ values (7, 1, 'Product 1', 'Description 1', 1212)
|
$$ values (7, 1, 'Product 1', 'Description 1', 1212, '{tag1}'::tag_name[])
|
||||||
, (8, 2, 'Product 2', 'Description 2', 2424)
|
, (8, 2, 'Product 2', 'Description 2', 2424, '{tag1,tag3}'::tag_name[])
|
||||||
, (9, 2, 'Product 3', 'Description 3', 3636)
|
, (9, 2, 'Product 3', 'Description 3', 3636, '{}'::tag_name[])
|
||||||
$$,
|
$$,
|
||||||
'Should have edited all three products'
|
'Should have edited all three products'
|
||||||
);
|
);
|
||||||
|
@ -126,24 +111,6 @@ select bag_eq(
|
||||||
'Should have updated the taxes for the products we told to'
|
'Should have updated the taxes for the products we told to'
|
||||||
);
|
);
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select company_id, name from tag $$,
|
|
||||||
$$ values (1, 'tag1')
|
|
||||||
, (2, 'tag1')
|
|
||||||
, (2, 'tag2')
|
|
||||||
, (2, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have added all new tags'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
$$ select product.name as product_name, tag.name as tag_name from product_tag join product using (product_id) join tag using (tag_id) $$,
|
|
||||||
$$ values ('Product 1', 'tag1')
|
|
||||||
, ('Product 2', 'tag1')
|
|
||||||
, ('Product 2', 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have assigned the tags to products'
|
|
||||||
);
|
|
||||||
|
|
||||||
select *
|
select *
|
||||||
from finish();
|
from finish();
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(78);
|
select plan(83);
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
set search_path to numerus, auth, public;
|
||||||
|
|
||||||
|
@ -75,6 +75,12 @@ select col_not_null('invoice', 'notes');
|
||||||
select col_has_default('invoice', 'notes');
|
select col_has_default('invoice', 'notes');
|
||||||
select col_default_is('invoice', 'notes', '');
|
select col_default_is('invoice', 'notes', '');
|
||||||
|
|
||||||
|
select has_column('invoice', 'tags');
|
||||||
|
select col_type_is('invoice', 'tags', 'tag_name[]');
|
||||||
|
select col_not_null('invoice', 'tags');
|
||||||
|
select col_has_default('invoice', 'tags');
|
||||||
|
select col_default_is('invoice', 'tags', '{}');
|
||||||
|
|
||||||
select has_column('invoice', 'payment_method_id');
|
select has_column('invoice', 'payment_method_id');
|
||||||
select col_is_fk('invoice', 'payment_method_id');
|
select col_is_fk('invoice', 'payment_method_id');
|
||||||
select fk_ok('invoice', 'payment_method_id', 'payment_method', 'payment_method_id');
|
select fk_ok('invoice', 'payment_method_id', 'payment_method', 'payment_method_id');
|
||||||
|
|
|
@ -1,136 +0,0 @@
|
||||||
-- Test invoice_tag
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(23);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_table('invoice_tag');
|
|
||||||
select has_pk('invoice_tag' );
|
|
||||||
select col_is_pk('invoice_tag', array['invoice_id', 'tag_id']);
|
|
||||||
select table_privs_are('invoice_tag', 'guest', array []::text[]);
|
|
||||||
select table_privs_are('invoice_tag', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('invoice_tag', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('invoice_tag', 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
select has_column('invoice_tag', 'invoice_id');
|
|
||||||
select col_is_fk('invoice_tag', 'invoice_id');
|
|
||||||
select fk_ok('invoice_tag', 'invoice_id', 'invoice', 'invoice_id');
|
|
||||||
select col_type_is('invoice_tag', 'invoice_id', 'integer');
|
|
||||||
select col_not_null('invoice_tag', 'invoice_id');
|
|
||||||
select col_hasnt_default('invoice_tag', 'invoice_id');
|
|
||||||
|
|
||||||
select has_column('invoice_tag', 'tag_id');
|
|
||||||
select col_is_fk('invoice_tag', 'tag_id');
|
|
||||||
select fk_ok('invoice_tag', 'tag_id', 'tag', 'tag_id');
|
|
||||||
select col_type_is('invoice_tag', 'tag_id', 'integer');
|
|
||||||
select col_not_null('invoice_tag', 'tag_id');
|
|
||||||
select col_hasnt_default('invoice_tag', 'tag_id');
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate invoice_tag cascade;
|
|
||||||
truncate invoice cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate contact cascade;
|
|
||||||
truncate company_user cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate auth."user" cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
|
|
||||||
values (1, 'demo@tandem.blog', 'Demo', 'test', 'invoicer', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
|
|
||||||
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 222)
|
|
||||||
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 444)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (444, 4, 'cash', 'cash')
|
|
||||||
, (222, 2, 'cash', 'cash')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into company_user (company_id, user_id)
|
|
||||||
values (2, 1)
|
|
||||||
, (4, 5)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
|
||||||
values (6, 2, 'Contact 1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
|
||||||
, (8, 4, 'Contact 2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice (invoice_id, company_id, invoice_number, contact_id, currency_code, payment_method_id)
|
|
||||||
values (10, 2, 'INV020001', 6, 'EUR', 222)
|
|
||||||
, (12, 4, 'INV040001', 8, 'EUR', 444)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (14, 2, 'web')
|
|
||||||
, (15, 2, 'design')
|
|
||||||
, (16, 4, 'product')
|
|
||||||
, (17, 4, 'development')
|
|
||||||
, (18, 4, 'something-else')
|
|
||||||
, (19, 4, 'design')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice_tag (invoice_id, tag_id)
|
|
||||||
values (10, 14)
|
|
||||||
, (10, 15)
|
|
||||||
, (12, 18)
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare invoice_tag_data as
|
|
||||||
select invoice_id, tag_id
|
|
||||||
from invoice_tag
|
|
||||||
;
|
|
||||||
|
|
||||||
set role invoicer;
|
|
||||||
select is_empty('invoice_tag_data', 'Should show no data when cookie is not set yet');
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'invoice_tag_data',
|
|
||||||
$$ values ( 10, 14 )
|
|
||||||
, ( 10, 15 )
|
|
||||||
$$,
|
|
||||||
'Should only list invoice tags of the companies where demo@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'invoice_tag_data',
|
|
||||||
$$ values ( 12, 18 )
|
|
||||||
$$,
|
|
||||||
'Should only list invoice tags of the companies where admin@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('not-a-cookie');
|
|
||||||
select throws_ok(
|
|
||||||
'invoice_tag_data',
|
|
||||||
'42501', 'permission denied for table invoice_tag',
|
|
||||||
'Should not allow select to guest users'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
reset role;
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
||||||
|
|
|
@ -5,7 +5,7 @@ reset client_min_messages;
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
select plan(51);
|
select plan(56);
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
set search_path to numerus, auth, public;
|
||||||
|
|
||||||
|
@ -58,6 +58,12 @@ select col_type_is('product', 'price', 'integer');
|
||||||
select col_not_null('product', 'price');
|
select col_not_null('product', 'price');
|
||||||
select col_hasnt_default('product', 'price');
|
select col_hasnt_default('product', 'price');
|
||||||
|
|
||||||
|
select has_column('product', 'tags');
|
||||||
|
select col_type_is('product', 'tags', 'tag_name[]');
|
||||||
|
select col_not_null('product', 'tags');
|
||||||
|
select col_has_default('product', 'tags');
|
||||||
|
select col_default_is('product', 'tags', '{}');
|
||||||
|
|
||||||
select has_column('product', 'created_at');
|
select has_column('product', 'created_at');
|
||||||
select col_type_is('product', 'created_at', 'timestamp with time zone');
|
select col_type_is('product', 'created_at', 'timestamp with time zone');
|
||||||
select col_not_null('product', 'created_at');
|
select col_not_null('product', 'created_at');
|
||||||
|
|
|
@ -1,129 +0,0 @@
|
||||||
-- Test product_tag
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(23);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_table('product_tag');
|
|
||||||
select has_pk('product_tag');
|
|
||||||
select col_is_pk('product_tag', array['product_id', 'tag_id']);
|
|
||||||
select table_privs_are('product_tag', 'guest', array []::text[]);
|
|
||||||
select table_privs_are('product_tag', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('product_tag', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('product_tag', 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
select has_column('product_tag', 'product_id');
|
|
||||||
select col_is_fk('product_tag', 'product_id');
|
|
||||||
select fk_ok('product_tag', 'product_id', 'product', 'product_id');
|
|
||||||
select col_type_is('product_tag', 'product_id', 'integer');
|
|
||||||
select col_not_null('product_tag', 'product_id');
|
|
||||||
select col_hasnt_default('product_tag', 'product_id');
|
|
||||||
|
|
||||||
select has_column('product_tag', 'tag_id');
|
|
||||||
select col_is_fk('product_tag', 'tag_id');
|
|
||||||
select fk_ok('product_tag', 'tag_id', 'tag', 'tag_id');
|
|
||||||
select col_type_is('product_tag', 'tag_id', 'integer');
|
|
||||||
select col_not_null('product_tag', 'tag_id');
|
|
||||||
select col_hasnt_default('product_tag', 'tag_id');
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate product_tag cascade;
|
|
||||||
truncate product cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate company_user cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate auth."user" cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
|
|
||||||
values (1, 'demo@tandem.blog', 'Demo', 'test', 'invoicer', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
|
|
||||||
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 222)
|
|
||||||
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 444)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (444, 4, 'cash', 'cash')
|
|
||||||
, (222, 2, 'cash', 'cash')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into company_user (company_id, user_id)
|
|
||||||
values (2, 1)
|
|
||||||
, (4, 5)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into product (product_id, company_id, name, description, price)
|
|
||||||
values (6, 2, 'Product 1', 'Description 1', 1200)
|
|
||||||
, (8, 4, 'Product 2', 'Description 2', 2400)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (14, 2, 'web')
|
|
||||||
, (15, 2, 'design')
|
|
||||||
, (16, 4, 'product')
|
|
||||||
, (17, 4, 'development')
|
|
||||||
, (18, 4, 'something-else')
|
|
||||||
, (19, 4, 'design')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into product_tag (product_id, tag_id)
|
|
||||||
values (6, 14)
|
|
||||||
, (6, 15)
|
|
||||||
, (8, 18)
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare product_tag_data as
|
|
||||||
select product_id, tag_id
|
|
||||||
from product_tag
|
|
||||||
;
|
|
||||||
|
|
||||||
set role invoicer;
|
|
||||||
select is_empty('product_tag_data', 'Should show no data when cookie is not set yet');
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'product_tag_data',
|
|
||||||
$$ values ( 6, 14 )
|
|
||||||
, ( 6, 15 )
|
|
||||||
$$,
|
|
||||||
'Should only list product tags of the companies where demo@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'product_tag_data',
|
|
||||||
$$ values ( 8, 18 )
|
|
||||||
$$,
|
|
||||||
'Should only list product tags of the companies where admin@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('not-a-cookie');
|
|
||||||
select throws_ok(
|
|
||||||
'product_tag_data',
|
|
||||||
'42501', 'permission denied for table product_tag',
|
|
||||||
'Should not allow select to guest users'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
||||||
|
|
139
test/tag.sql
139
test/tag.sql
|
@ -1,139 +0,0 @@
|
||||||
-- Test tag
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(33);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_table('tag');
|
|
||||||
select has_pk('tag' );
|
|
||||||
select table_privs_are('tag', 'guest', array []::text[]);
|
|
||||||
select table_privs_are('tag', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('tag', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
|
||||||
select table_privs_are('tag', 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
select has_sequence('tag_tag_id_seq');
|
|
||||||
select sequence_privs_are('tag_tag_id_seq', 'guest', array[]::text[]);
|
|
||||||
select sequence_privs_are('tag_tag_id_seq', 'invoicer', array['USAGE']);
|
|
||||||
select sequence_privs_are('tag_tag_id_seq', 'admin', array['USAGE']);
|
|
||||||
select sequence_privs_are('tag_tag_id_seq', 'authenticator', array[]::text[]);
|
|
||||||
|
|
||||||
select has_column('tag', 'tag_id');
|
|
||||||
select col_is_pk('tag', 'tag_id');
|
|
||||||
select col_type_is('tag', 'tag_id', 'integer');
|
|
||||||
select col_not_null('tag', 'tag_id');
|
|
||||||
select col_has_default('tag', 'tag_id');
|
|
||||||
select col_default_is('tag', 'tag_id', 'nextval(''tag_tag_id_seq''::regclass)');
|
|
||||||
|
|
||||||
select has_column('tag', 'company_id');
|
|
||||||
select col_is_fk('tag', 'company_id');
|
|
||||||
select fk_ok('tag', 'company_id', 'company', 'company_id');
|
|
||||||
select col_type_is('tag', 'company_id', 'integer');
|
|
||||||
select col_not_null('tag', 'company_id');
|
|
||||||
select col_hasnt_default('tag', 'company_id');
|
|
||||||
|
|
||||||
select has_column('tag', 'name');
|
|
||||||
select col_type_is('tag', 'name', 'tag_name');
|
|
||||||
select col_not_null('tag', 'name');
|
|
||||||
select col_hasnt_default('tag', 'name');
|
|
||||||
select col_is_unique('tag', array['company_id', 'name']);
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate company_user cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate auth."user" cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
|
|
||||||
values (1, 'demo@tandem.blog', 'Demo', 'test', 'invoicer', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
|
|
||||||
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 222)
|
|
||||||
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 444)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (444, 4, 'cash', 'cash')
|
|
||||||
, (222, 2, 'cash', 'cash')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into company_user (company_id, user_id)
|
|
||||||
values (2, 1)
|
|
||||||
, (4, 5)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into tag (company_id, name)
|
|
||||||
values (2, 'web')
|
|
||||||
, (2, 'design')
|
|
||||||
, (4, 'product')
|
|
||||||
, (4, 'development')
|
|
||||||
, (4, 'something-else')
|
|
||||||
, (4, 'design')
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare tag_data as
|
|
||||||
select company_id, name
|
|
||||||
from tag
|
|
||||||
;
|
|
||||||
|
|
||||||
set role invoicer;
|
|
||||||
select is_empty('tag_data', 'Should show no data when cookie is not set yet');
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'tag_data',
|
|
||||||
$$ values ( 2, 'web' )
|
|
||||||
, ( 2, 'design' )
|
|
||||||
$$,
|
|
||||||
'Should only list tags of the companies where demo@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
|
|
||||||
select bag_eq(
|
|
||||||
'tag_data',
|
|
||||||
$$ values (4, 'product' )
|
|
||||||
, (4, 'development' )
|
|
||||||
, (4, 'something-else' )
|
|
||||||
, (4, 'design' )
|
|
||||||
$$,
|
|
||||||
'Should only list tags of the companies where admin@tandem.blog is user of'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select set_cookie('not-a-cookie');
|
|
||||||
select throws_ok(
|
|
||||||
'tag_data',
|
|
||||||
'42501', 'permission denied for table tag',
|
|
||||||
'Should not allow select to guest users'
|
|
||||||
);
|
|
||||||
reset role;
|
|
||||||
|
|
||||||
select throws_ok( $$
|
|
||||||
insert into tag (company_id, name)
|
|
||||||
values (2, 'web')
|
|
||||||
$$,
|
|
||||||
'23505', 'duplicate key value violates unique constraint "tag_company_id_name_key"',
|
|
||||||
'Should not allow repeated tag names within the same company'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
||||||
|
|
|
@ -1,124 +0,0 @@
|
||||||
-- Test tag_contact
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(17);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_function('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]']);
|
|
||||||
select function_lang_is('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'sql');
|
|
||||||
select function_returns('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'void');
|
|
||||||
select isnt_definer('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]']);
|
|
||||||
select volatility_is('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'volatile');
|
|
||||||
select function_privs_are('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'guest', array []::text[]);
|
|
||||||
select function_privs_are('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_contact', array ['integer', 'integer', 'tag_name[]'], 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate contact_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate contact cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (111, 1, 'cash', 'cash')
|
|
||||||
, (112, 1, 'bank', 'send money to my bank account')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (10, 1, 'tag1')
|
|
||||||
, (11, 1, 'tag2')
|
|
||||||
;
|
|
||||||
-- tag_contact uses the sequence and sometimes it would confict
|
|
||||||
alter sequence tag_tag_id_seq restart with 15;
|
|
||||||
|
|
||||||
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
|
||||||
values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
|
||||||
, (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into contact_tag (contact_id, tag_id)
|
|
||||||
values (12, 10)
|
|
||||||
, (13, 11)
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare current_tags as
|
|
||||||
select contact_id, tag.name
|
|
||||||
from contact
|
|
||||||
join contact_tag using (contact_id)
|
|
||||||
join tag using (tag_id);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_contact(1, 12, array['tag1']) $$,
|
|
||||||
'Should be able to keep the same tags to the contact'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (12, 'tag1')
|
|
||||||
, (13, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should not have changed any contact tag'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_contact(1, 12, array['tag1', 'tag2']) $$,
|
|
||||||
'Should be able to add tag2 contact'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (12, 'tag1')
|
|
||||||
, (12, 'tag2')
|
|
||||||
, (13, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have added tag2 to contact'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_contact(1, 13, array['tag3']) $$,
|
|
||||||
'Should be able to replace all tags of an contact with a new one'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (12, 'tag1')
|
|
||||||
, (12, 'tag2')
|
|
||||||
, (13, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have set tag3 to contact'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_contact(1, 12, array[]::tag_name[]) $$,
|
|
||||||
'Should be able to remove all tags from an contact'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (13, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have remove all tags from contact'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,130 +0,0 @@
|
||||||
-- Test tag_invoice
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(17);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_function('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]']);
|
|
||||||
select function_lang_is('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'sql');
|
|
||||||
select function_returns('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'void');
|
|
||||||
select isnt_definer('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]']);
|
|
||||||
select volatility_is('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'volatile');
|
|
||||||
select function_privs_are('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'guest', array []::text[]);
|
|
||||||
select function_privs_are('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_invoice', array ['integer', 'integer', 'tag_name[]'], 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate invoice_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate invoice cascade;
|
|
||||||
truncate contact cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (111, 1, 'cash', 'cash')
|
|
||||||
, (112, 1, 'bank', 'send money to my bank account')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (10, 1, 'tag1')
|
|
||||||
, (11, 1, 'tag2')
|
|
||||||
;
|
|
||||||
-- tag_invoice uses the sequence and sometimes it would confict
|
|
||||||
alter sequence tag_tag_id_seq restart with 15;
|
|
||||||
|
|
||||||
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
|
||||||
values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
|
||||||
, (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice (invoice_id, company_id, slug, invoice_number, invoice_date, contact_id, payment_method_id, currency_code)
|
|
||||||
values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'INV1', '2023-03-10', 12, 111, 'EUR')
|
|
||||||
, (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'INV2', '2023-03-09', 13, 111, 'EUR')
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice_tag (invoice_id, tag_id)
|
|
||||||
values (15, 10)
|
|
||||||
, (16, 11)
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare current_tags as
|
|
||||||
select invoice_id, tag.name
|
|
||||||
from invoice
|
|
||||||
join invoice_tag using (invoice_id)
|
|
||||||
join tag using (tag_id);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_invoice(1, 15, array['tag1']) $$,
|
|
||||||
'Should be able to keep the same tags to the invoice'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (15, 'tag1')
|
|
||||||
, (16, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should not have changed any invoice tag'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_invoice(1, 15, array['tag1', 'tag2']) $$,
|
|
||||||
'Should be able to add tag2 invoice'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (15, 'tag1')
|
|
||||||
, (15, 'tag2')
|
|
||||||
, (16, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have added tag2 to invoice'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_invoice(1, 16, array['tag3']) $$,
|
|
||||||
'Should be able to replace all tags of an invoice with a new one'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (15, 'tag1')
|
|
||||||
, (15, 'tag2')
|
|
||||||
, (16, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have set tag3 to invoice'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_invoice(1, 15, array[]::tag_name[]) $$,
|
|
||||||
'Should be able to remove all tags from an invoice'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (16, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have remove all tags from invoice'
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,124 +0,0 @@
|
||||||
-- Test tag_product
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select plan(17);
|
|
||||||
|
|
||||||
set search_path to numerus, auth, public;
|
|
||||||
|
|
||||||
select has_function('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]']);
|
|
||||||
select function_lang_is('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'sql');
|
|
||||||
select function_returns('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'void');
|
|
||||||
select isnt_definer('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]']);
|
|
||||||
select volatility_is('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'volatile');
|
|
||||||
select function_privs_are('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'guest', array []::text[]);
|
|
||||||
select function_privs_are('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_product', array ['integer', 'integer', 'tag_name[]'], 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
|
||||||
truncate product_tag cascade;
|
|
||||||
truncate tag cascade;
|
|
||||||
truncate product cascade;
|
|
||||||
truncate payment_method cascade;
|
|
||||||
truncate company cascade;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" deferred;
|
|
||||||
|
|
||||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
|
||||||
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
||||||
values (111, 1, 'cash', 'cash')
|
|
||||||
, (112, 1, 'bank', 'send money to my bank account')
|
|
||||||
;
|
|
||||||
|
|
||||||
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
||||||
|
|
||||||
insert into tag (tag_id, company_id, name)
|
|
||||||
values (10, 1, 'tag1')
|
|
||||||
, (11, 1, 'tag2')
|
|
||||||
;
|
|
||||||
-- tag_product uses the sequence and sometimes it would confict
|
|
||||||
alter sequence tag_tag_id_seq restart with 15;
|
|
||||||
|
|
||||||
|
|
||||||
insert into product (product_id, company_id, name, description, price)
|
|
||||||
values (12, 1, 'Product 1', 'Description 1', 1200)
|
|
||||||
, (13, 1, 'Product 2', 'Description 2', 2400)
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into product_tag (product_id, tag_id)
|
|
||||||
values (12, 10)
|
|
||||||
, (13, 11)
|
|
||||||
;
|
|
||||||
|
|
||||||
prepare current_tags as
|
|
||||||
select product_id, tag.name
|
|
||||||
from product
|
|
||||||
join product_tag using (product_id)
|
|
||||||
join tag using (tag_id);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_product(1, 12, array['tag1']) $$,
|
|
||||||
'Should be able to keep the same tags to the product'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (12, 'tag1')
|
|
||||||
, (13, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should not have changed any product tag'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_product(1, 12, array['tag1', 'tag2']) $$,
|
|
||||||
'Should be able to add tag2 product'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (12, 'tag1')
|
|
||||||
, (12, 'tag2')
|
|
||||||
, (13, 'tag2')
|
|
||||||
$$,
|
|
||||||
'Should have added tag2 to product'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_product(1, 13, array['tag3']) $$,
|
|
||||||
'Should be able to replace all tags of an product with a new one'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (12, 'tag1')
|
|
||||||
, (12, 'tag2')
|
|
||||||
, (13, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have set tag3 to product'
|
|
||||||
);
|
|
||||||
|
|
||||||
select lives_ok(
|
|
||||||
$$ select tag_product(1, 12, array[]::tag_name[]) $$,
|
|
||||||
'Should be able to remove all tags from an product'
|
|
||||||
);
|
|
||||||
|
|
||||||
select bag_eq(
|
|
||||||
'current_tags',
|
|
||||||
$$ values (13, 'tag3')
|
|
||||||
$$,
|
|
||||||
'Should have remove all tags from product'
|
|
||||||
);
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,25 +0,0 @@
|
||||||
-- Test tag_relation
|
|
||||||
set client_min_messages to warning;
|
|
||||||
create extension if not exists pgtap;
|
|
||||||
reset client_min_messages;
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
set search_path to numerus, public;
|
|
||||||
|
|
||||||
select plan(9);
|
|
||||||
|
|
||||||
select has_function('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]']);
|
|
||||||
select function_lang_is('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'plpgsql');
|
|
||||||
select function_returns('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'void');
|
|
||||||
select isnt_definer('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]']);
|
|
||||||
select volatility_is('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'volatile');
|
|
||||||
select function_privs_are('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'guest', array []::text[]);
|
|
||||||
select function_privs_are('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
|
||||||
select function_privs_are('numerus', 'tag_relation', array ['regclass', 'name', 'integer', 'integer', 'tag_name[]'], 'authenticator', array []::text[]);
|
|
||||||
|
|
||||||
select *
|
|
||||||
from finish();
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -16,6 +16,7 @@ select contact_id
|
||||||
, province
|
, province
|
||||||
, postal_code
|
, postal_code
|
||||||
, country_code
|
, country_code
|
||||||
|
, tags
|
||||||
, created_at
|
, created_at
|
||||||
from numerus.contact
|
from numerus.contact
|
||||||
where false;
|
where false;
|
||||||
|
|
|
@ -1,13 +0,0 @@
|
||||||
-- Verify numerus:contact_tag on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select contact_id
|
|
||||||
, tag_id
|
|
||||||
from numerus.contact_tag
|
|
||||||
where false;
|
|
||||||
|
|
||||||
select 1 / count(*) from pg_class where oid = 'numerus.contact_tag'::regclass and relrowsecurity;
|
|
||||||
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.contact_tag'::regclass;
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -10,6 +10,7 @@ select invoice_id
|
||||||
, contact_id
|
, contact_id
|
||||||
, invoice_status
|
, invoice_status
|
||||||
, notes
|
, notes
|
||||||
|
, tags
|
||||||
, payment_method_id
|
, payment_method_id
|
||||||
, currency_code
|
, currency_code
|
||||||
, created_at
|
, created_at
|
||||||
|
|
|
@ -1,13 +0,0 @@
|
||||||
-- Verify numerus:invoice_tag on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select invoice_id
|
|
||||||
, tag_id
|
|
||||||
from numerus.invoice_tag
|
|
||||||
where false;
|
|
||||||
|
|
||||||
select 1 / count(*) from pg_class where oid = 'numerus.invoice_tag'::regclass and relrowsecurity;
|
|
||||||
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.invoice_tag'::regclass;
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -8,6 +8,7 @@ select product_id
|
||||||
, name
|
, name
|
||||||
, description
|
, description
|
||||||
, price
|
, price
|
||||||
|
, tags
|
||||||
, created_at
|
, created_at
|
||||||
from numerus.product
|
from numerus.product
|
||||||
where false;
|
where false;
|
||||||
|
|
|
@ -1,13 +0,0 @@
|
||||||
-- Verify numerus:product_tag on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select product_id
|
|
||||||
, tag_id
|
|
||||||
from numerus.product_tag
|
|
||||||
where false;
|
|
||||||
|
|
||||||
select 1 / count(*) from pg_class where oid = 'numerus.product_tag'::regclass and relrowsecurity;
|
|
||||||
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.product_tag'::regclass;
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,14 +0,0 @@
|
||||||
-- Verify numerus:tag on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select tag_id
|
|
||||||
, company_id
|
|
||||||
, name
|
|
||||||
from numerus.tag
|
|
||||||
where false;
|
|
||||||
|
|
||||||
select 1 / count(*) from pg_class where oid = 'numerus.tag'::regclass and relrowsecurity;
|
|
||||||
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.tag'::regclass;
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Verify numerus:tag_contact on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select has_function_privilege('numerus.tag_contact(integer, integer, numerus.tag_name[])', 'execute');
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Verify numerus:tag_invoice on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select has_function_privilege('numerus.tag_invoice(integer, integer, numerus.tag_name[])', 'execute');
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Verify numerus:tag_product on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select has_function_privilege('numerus.tag_product(integer, integer, numerus.tag_name[])', 'execute');
|
|
||||||
|
|
||||||
rollback;
|
|
|
@ -1,7 +0,0 @@
|
||||||
-- Verify numerus:tag_relation on pg
|
|
||||||
|
|
||||||
begin;
|
|
||||||
|
|
||||||
select has_function_privilege('numerus.tag_relation(regclass, name, integer, integer, numerus.tag_name[])', 'execute');
|
|
||||||
|
|
||||||
rollback;
|
|
Loading…
Reference in New Issue