Add SQL and helper PL/pgSQL functions to tag invoices
We plan to tag also contacts and products using the same tag relation, but different invoice_tag, contact_tag, and product_tag relations for each one. However, the logic is the same for all three, hence it makes more sense to put it into a PL/pgSQL with dynamic SQL. Moreover, the SQL for tagging in add_invoice and edit_invoice where almost exactly the same, the only difference was deleting the existing tags when editing. I do not execute the tag_relation function in its test suite because by itself it does nothing without supporting invoice_tag, contact_tag, or any such relation, so it is being tested in the suite for tag_invoice.
This commit is contained in:
parent
7e8ec539ff
commit
6b73acafe6
|
@ -10,8 +10,7 @@
|
||||||
-- requires: invoice_product_tax
|
-- requires: invoice_product_tax
|
||||||
-- requires: next_invoice_number
|
-- requires: next_invoice_number
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: tag
|
-- requires: tag_invoice
|
||||||
-- requires: invoice_tag
|
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -64,19 +63,7 @@ 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;
|
||||||
|
|
||||||
if array_length(tags, 1) > 0 then
|
perform tag_invoice(company, iid, tags);
|
||||||
insert into tag (company_id, name)
|
|
||||||
select add_invoice.company, new_tag.name
|
|
||||||
from unnest (tags) as new_tag(name)
|
|
||||||
on conflict (company_id, name) do nothing
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice_tag (invoice_id, tag_id)
|
|
||||||
select iid, tag_id
|
|
||||||
from tag
|
|
||||||
join unnest (tags) as new_tag(name) on company_id = add_invoice.company and tag.name = new_tag.name
|
|
||||||
;
|
|
||||||
end if;
|
|
||||||
|
|
||||||
return pslug;
|
return pslug;
|
||||||
end;
|
end;
|
||||||
|
|
|
@ -8,8 +8,7 @@
|
||||||
-- requires: invoice_product
|
-- requires: invoice_product
|
||||||
-- requires: invoice_product_tax
|
-- requires: invoice_product_tax
|
||||||
-- requires: tag_name
|
-- requires: tag_name
|
||||||
-- requires: tag
|
-- requires: tag_invoice
|
||||||
-- requires: invoice_tag
|
|
||||||
|
|
||||||
begin;
|
begin;
|
||||||
|
|
||||||
|
@ -90,21 +89,7 @@ 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;
|
||||||
|
|
||||||
delete from invoice_tag where invoice_id = iid;
|
perform tag_invoice(company, iid, tags);
|
||||||
|
|
||||||
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
|
|
||||||
;
|
|
||||||
|
|
||||||
insert into invoice_tag (invoice_id, tag_id)
|
|
||||||
select iid, tag_id
|
|
||||||
from tag
|
|
||||||
join unnest (tags) as new_tag(name) on company_id = company and tag.name = new_tag.name
|
|
||||||
;
|
|
||||||
end if;
|
|
||||||
|
|
||||||
return invoice_slug;
|
return invoice_slug;
|
||||||
end;
|
end;
|
||||||
|
|
|
@ -0,0 +1,21 @@
|
||||||
|
-- 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;
|
|
@ -0,0 +1,32 @@
|
||||||
|
-- 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;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:tag_invoice from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.tag_invoice(integer, integer, numerus.tag_name[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:tag_relation from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.tag_relation(regclass, name, integer, integer, numerus.tag_name[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -61,11 +61,13 @@ next_invoice_number [schema_numerus invoice_number_counter] 2023-02-17T13:21:48Z
|
||||||
tag_name [schema_numerus] 2023-03-10T11:06:11Z jordi fita mas <jordi@tandem.blog> # Add domain for tag names
|
tag_name [schema_numerus] 2023-03-10T11:06:11Z jordi fita mas <jordi@tandem.blog> # Add domain for tag names
|
||||||
tag [schema_numerus tag_name] 2023-03-10T11:04:24Z jordi fita mas <jordi@tandem.blog> # Add relation for tags
|
tag [schema_numerus tag_name] 2023-03-10T11:04:24Z jordi fita mas <jordi@tandem.blog> # Add relation for tags
|
||||||
invoice_tag [schema_numerus tag invoice] 2023-03-10T11:37:43Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice tag
|
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 tag invoice_tag] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices
|
tag_relation [schema_numerus tag tag_name] 2023-03-25T17:40:52Z jordi fita mas <jordi@tandem.blog> # Add function to tag “relations”
|
||||||
|
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_tag] 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 tag_invoice] 2023-03-11T18:30:50Z jordi fita mas <jordi@tandem.blog> # Add function to edit invoices
|
||||||
|
|
|
@ -0,0 +1,130 @@
|
||||||
|
-- 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;
|
|
@ -0,0 +1,25 @@
|
||||||
|
-- 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;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:tag_invoice on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select has_function_privilege('numerus.tag_invoice(integer, integer, numerus.tag_name[])', 'execute');
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- 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