Add attach_to_expense SQL function

Just to avoid SQL “logic” in Go source.
This commit is contained in:
jordi fita mas 2023-05-15 12:38:40 +02:00
parent ee2ed598a3
commit 7921b9cf80
6 changed files with 138 additions and 2 deletions

View File

@ -0,0 +1,29 @@
-- Deploy numerus:attach_to_expense to pg
-- requires: schema_numerus
-- requires: expense
-- requires: expense_attachment
begin;
set search_path to numerus, public;
create or replace function attach_to_expense(expense_slug uuid, original_filename text, mime_type text, content bytea) returns void as
$$
insert into expense_attachment (expense_id, original_filename, mime_type, content)
select expense_id, original_filename, mime_type, content
from expense
where slug = expense_slug
on conflict (expense_id) do update
set original_filename = excluded.original_filename
, mime_type = excluded.mime_type
, content = excluded.content
;
$$
language sql
;
revoke execute on function attach_to_expense(uuid, text, text, bytea) from public;
grant execute on function attach_to_expense(uuid, text, text, bytea) to invoicer;
grant execute on function attach_to_expense(uuid, text, text, bytea) to admin;
commit;

View File

@ -283,7 +283,7 @@ func HandleAddExpense(w http.ResponseWriter, r *http.Request, _ httprouter.Param
taxes := mustSliceAtoi(form.Tax.Selected)
slug := conn.MustGetText(r.Context(), "", "select add_expense($1, $2, $3, $4, $5, $6, $7)", company.Id, form.InvoiceDate, form.Invoicer, form.InvoiceNumber, form.Amount, taxes, form.Tags)
if len(form.File.Content) > 0 {
conn.MustQuery(r.Context(), "insert into expense_attachment(expense_id, original_filename, mime_type, content) select expense_id, $1, $2, $3 from expense where slug = $4", form.File.OriginalFileName, form.File.ContentType, form.File.Content, slug)
conn.MustQuery(r.Context(), "select attach_to_expense($1, $2, $3, $4)", slug, form.File.OriginalFileName, form.File.ContentType, form.File.Content)
}
htmxRedirect(w, r, companyURI(company, "/expenses"))
}
@ -315,7 +315,7 @@ func HandleUpdateExpense(w http.ResponseWriter, r *http.Request, params httprout
return
}
if len(form.File.Content) > 0 {
conn.MustQuery(r.Context(), "insert into expense_attachment(expense_id, original_filename, mime_type, content) select expense_id, $1, $2, $3 from expense where slug = $4 on conflict (expense_id) do update set original_filename = excluded.original_filename, mime_type = excluded.mime_type, content = excluded.content", form.File.OriginalFileName, form.File.ContentType, form.File.Content, slug)
conn.MustQuery(r.Context(), "select attach_to_expense($1, $2, $3, $4)", slug, form.File.OriginalFileName, form.File.ContentType, form.File.Content)
}
htmxRedirect(w, r, companyURI(company, "/expenses"))
}

View File

@ -0,0 +1,7 @@
-- Revert numerus:attach_to_expense from pg
begin;
drop function if exists numerus.attach_to_expense(uuid, text, text, bytea);
commit;

View File

@ -75,3 +75,4 @@ expense_tax [schema_numerus expense tax tax_rate] 2023-05-01T14:08:33Z jordi fit
add_expense [schema_numerus expense expense_tax tax company currency parse_price tag_name] 2023-05-02T08:00:26Z jordi fita mas <jordi@tandem.blog> # Add function to create new expenses
edit_expense [schema_numerus expense currency parse_price tax tag_name] 2023-05-04T09:53:04Z jordi fita mas <jordi@tandem.blog> # Add function to edit expenses
expense_attachment [schema_numerus expense] 2023-05-13T19:11:21Z jordi fita mas <jordi@tandem.blog> # Add relation of expense attachments
attach_to_expense [schema_numerus expense expense_attachment] 2023-05-15T10:18:31Z jordi fita mas <jordi@tandem.blog> # Add function to attach documents to expenses

View File

@ -0,0 +1,92 @@
-- Test attach_to_expense
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(12);
set search_path to auth, numerus, public;
select has_function('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea']);
select function_lang_is('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'sql');
select function_returns('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'void');
select isnt_definer('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea']);
select volatility_is('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'volatile');
select function_privs_are('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'guest', array []::text[]);
select function_privs_are('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'invoicer', array ['EXECUTE']);
select function_privs_are('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'admin', array ['EXECUTE']);
select function_privs_are('numerus', 'attach_to_expense', array ['uuid', 'text', 'text', 'bytea'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate expense_attachment cascade;
truncate expense cascade;
truncate contact cascade;
truncate tax cascade;
truncate tax_class 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 tax_class (tax_class_id, company_id, name)
values (11, 1, '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)
;
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 expense (expense_id, company_id, slug, invoice_number, invoice_date, contact_id, amount, currency_code, tags)
values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'INV1', '2023-05-04', 12, 111, 'EUR', '{tag1}')
, (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'INV2', '2023-05-05', 13, 222, 'EUR', '{tag2}')
;
insert into expense_attachment (expense_id, original_filename, mime_type, content)
values (16, 'something.txt', 'text/plain', convert_to('Once upon a time…', 'UTF-8'))
;
select lives_ok(
$$ select attach_to_expense('7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'expense.txt', 'text/plain', convert_to('Total 42€', 'UTF-8')) $$,
'Should be able to attach a document to the first expense'
);
select lives_ok(
$$ select attach_to_expense('b57b980b-247b-4be4-a0b7-03a7819c53ae', 'expense.html', 'text/html', convert_to('<html><p>Total 42€</p></html>', 'UTF-8')) $$,
'Should be able to replace the second expenses attachment with a new document'
);
select bag_eq(
$$ select expense_id, original_filename, mime_type, content from expense_attachment $$,
$$ values (15, 'expense.txt', 'text/plain', convert_to('Total 42€', 'UTF-8'))
, (16, 'expense.html', 'text/html', convert_to('<html><p>Total 42€</p></html>', 'UTF-8'))
$$,
'Should have attached all documents'
);
select *
from finish();
rollback;

View File

@ -0,0 +1,7 @@
-- Verify numerus:attach_to_expense on pg
begin;
select has_function_privilege('numerus.attach_to_expense(uuid, text, text, bytea)', 'execute');
rollback;