2023-02-14 11:39:54 +00:00
|
|
|
|
-- Test edit_product
|
|
|
|
|
set client_min_messages to warning;
|
|
|
|
|
create extension if not exists pgtap;
|
|
|
|
|
reset client_min_messages;
|
|
|
|
|
|
|
|
|
|
begin;
|
|
|
|
|
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
|
select plan(15);
|
2023-02-14 11:39:54 +00:00
|
|
|
|
|
|
|
|
|
set search_path to auth, numerus, public;
|
|
|
|
|
|
2023-03-26 11:51:57 +00:00
|
|
|
|
select has_function('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]']);
|
|
|
|
|
select function_lang_is('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'plpgsql');
|
|
|
|
|
select function_returns('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'boolean');
|
|
|
|
|
select isnt_definer('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]']);
|
|
|
|
|
select volatility_is('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'volatile');
|
|
|
|
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'guest', array []::text[]);
|
|
|
|
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
|
|
|
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
|
|
|
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]', 'tag_name[]'], 'authenticator', array []::text[]);
|
2023-02-14 11:39:54 +00:00
|
|
|
|
|
|
|
|
|
|
|
|
|
|
set client_min_messages to warning;
|
|
|
|
|
truncate product_tax cascade;
|
|
|
|
|
truncate product cascade;
|
|
|
|
|
truncate tax cascade;
|
2023-02-28 11:02:27 +00:00
|
|
|
|
truncate tax_class cascade;
|
2023-03-04 21:15:52 +00:00
|
|
|
|
truncate payment_method cascade;
|
2023-02-14 11:39:54 +00:00
|
|
|
|
truncate company cascade;
|
|
|
|
|
reset client_min_messages;
|
|
|
|
|
|
2023-03-04 21:15:52 +00:00
|
|
|
|
set constraints "company_default_payment_method_id_fkey" deferred;
|
2023-02-14 11:39:54 +00:00
|
|
|
|
|
2023-03-04 21:15:52 +00:00
|
|
|
|
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)
|
|
|
|
|
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 222)
|
2023-02-14 11:39:54 +00:00
|
|
|
|
;
|
|
|
|
|
|
2023-03-04 21:15:52 +00:00
|
|
|
|
insert into payment_method (payment_method_id, company_id, name, instructions)
|
|
|
|
|
values (111, 1, 'cash', 'cash')
|
|
|
|
|
, (222, 2, 'cash', 'cash')
|
|
|
|
|
;
|
|
|
|
|
|
|
|
|
|
set constraints "company_default_payment_method_id_fkey" immediate;
|
|
|
|
|
|
2023-02-28 11:02:27 +00:00
|
|
|
|
insert into tax_class (tax_class_id, company_id, name)
|
|
|
|
|
values (11, 1, 'tax')
|
|
|
|
|
, (22, 2, 'tax')
|
|
|
|
|
;
|
|
|
|
|
|
|
|
|
|
insert into tax (tax_id, company_id, tax_class_id, name, rate)
|
|
|
|
|
values (3, 1, 11, 'IRPF -15 %', -0.15)
|
|
|
|
|
, (4, 1, 11, 'IVA 21 %', 0.21)
|
|
|
|
|
, (5, 2, 22, 'IRPF -7 %', -0.07)
|
|
|
|
|
, (6, 2, 22, 'IVA 10 %', 0.10)
|
2023-02-14 11:39:54 +00:00
|
|
|
|
;
|
|
|
|
|
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
|
insert into product (product_id, company_id, slug, name, description, price, tags)
|
|
|
|
|
values (7, 1, 'd2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 01', 'Description01', 1200, '{tag1}')
|
|
|
|
|
, (8, 2, '2f085b8b-da90-41fe-b8cf-6ba8d94cfa38', 'Product 02', 'Description02', 2400, '{tag2}')
|
|
|
|
|
, (9, 2, '84044d0b-af33-442a-95a6-21efc77260d5', 'Product 03', 'Description03', 3600, '{tag2}')
|
2023-02-14 11:39:54 +00:00
|
|
|
|
;
|
|
|
|
|
|
|
|
|
|
insert into product_tax (product_id, tax_id)
|
|
|
|
|
values (7, 3)
|
|
|
|
|
, (8, 5)
|
|
|
|
|
, (9, 5)
|
|
|
|
|
, (9, 6)
|
|
|
|
|
;
|
|
|
|
|
|
2023-03-26 11:51:57 +00:00
|
|
|
|
|
2023-02-14 11:39:54 +00:00
|
|
|
|
select is(
|
2023-03-26 11:51:57 +00:00
|
|
|
|
edit_product('d2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 1', 'Description 1', '12.12', array[3, 4], array['tag1']),
|
2023-02-14 11:39:54 +00:00
|
|
|
|
true,
|
|
|
|
|
'Should be able to edit product from first company'
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
select is(
|
2023-03-26 11:51:57 +00:00
|
|
|
|
edit_product('2f085b8b-da90-41fe-b8cf-6ba8d94cfa38', 'Product 2', 'Description 2', '24.24', array[6], array['tag1', 'tag3']),
|
2023-02-14 11:39:54 +00:00
|
|
|
|
true,
|
|
|
|
|
'Should be able to edit product from second company'
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
select is(
|
2023-03-26 11:51:57 +00:00
|
|
|
|
edit_product('84044d0b-af33-442a-95a6-21efc77260d5', 'Product 3', 'Description 3', '36.36', array[]::integer[], array[]::tag_name[]),
|
2023-02-14 11:39:54 +00:00
|
|
|
|
true,
|
|
|
|
|
'Should be able to edit a product a remove all taxes'
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
select is(
|
2023-03-26 11:51:57 +00:00
|
|
|
|
edit_product('87e158d1-a0f5-48a7-854b-b86d7b4bb21c', 'Product 4', 'Description 4', '48.48', array[]::integer[], array[]::tag_name[]),
|
2023-02-14 11:39:54 +00:00
|
|
|
|
false,
|
|
|
|
|
'Should return false when the product does not exist'
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
select bag_eq(
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
|
$$ select product_id, company_id, name, description, price, tags from product $$,
|
|
|
|
|
$$ values (7, 1, 'Product 1', 'Description 1', 1212, '{tag1}'::tag_name[])
|
|
|
|
|
, (8, 2, 'Product 2', 'Description 2', 2424, '{tag1,tag3}'::tag_name[])
|
|
|
|
|
, (9, 2, 'Product 3', 'Description 3', 3636, '{}'::tag_name[])
|
2023-02-14 11:39:54 +00:00
|
|
|
|
$$,
|
|
|
|
|
'Should have edited all three products'
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
select bag_eq(
|
|
|
|
|
$$ select product_id, tax_id from product_tax $$,
|
|
|
|
|
$$ values (7, 3)
|
|
|
|
|
, (7, 4)
|
|
|
|
|
, (8, 6)
|
|
|
|
|
$$,
|
|
|
|
|
'Should have updated the taxes for the products we told to'
|
|
|
|
|
);
|
|
|
|
|
|
2023-03-26 11:51:57 +00:00
|
|
|
|
|
2023-02-14 11:39:54 +00:00
|
|
|
|
select *
|
|
|
|
|
from finish();
|
|
|
|
|
|
|
|
|
|
rollback;
|