From ebb073166ac7c0c0825a0be264f9e4e66cdcca9f Mon Sep 17 00:00:00 2001 From: jordi fita mas Date: Thu, 30 Jan 2025 23:24:16 +0100 Subject: [PATCH] Subsume collections into payments, and record payments in negative MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit This is to handle refunds, which are invoices with negative amounts, that can be both issued or received (i.e., an “expense”). The API provided by PostgreSQL is mostly the same, and internally it deals with negatives, so the Go package only had to change selects of collection. --- deploy/_merge_collection_into_payment.sql | 45 +++++ deploy/add_collection.sql | 12 +- deploy/add_collection@v3.sql | 68 +++++++ deploy/add_payment.sql | 2 +- deploy/add_payment@v3.sql | 67 +++++++ deploy/attach_to_collection.sql | 14 +- deploy/attach_to_collection@v3.sql | 30 +++ deploy/edit_collection.sql | 16 +- deploy/edit_collection@v3.sql | 53 +++++ deploy/edit_payment.sql | 2 +- deploy/edit_payment@v3.sql | 53 +++++ deploy/invoice_payment.sql | 32 +++ deploy/remove_collection.sql | 14 +- deploy/remove_collection@v3.sql | 40 ++++ deploy/update_expense_payment_status.sql | 6 +- deploy/update_expense_payment_status@v3.sql | 51 +++++ deploy/update_invoice_collection_status.sql | 22 ++- .../update_invoice_collection_status@v3.sql | 49 +++++ pkg/expenses.go | 3 +- pkg/invoices.go | 6 +- pkg/payments.go | 68 ++----- revert/_merge_collection_into_payment.sql | 120 +++++++++++ revert/add_collection.sql | 65 +++++- revert/add_collection@v3.sql | 7 + revert/add_payment.sql | 64 +++++- revert/add_payment@v3.sql | 7 + revert/attach_to_collection.sql | 27 ++- revert/attach_to_collection@v3.sql | 7 + revert/edit_collection.sql | 50 ++++- revert/edit_collection@v3.sql | 7 + revert/edit_payment.sql | 50 ++++- revert/edit_payment@v3.sql | 7 + revert/invoice_payment.sql | 7 + revert/remove_collection.sql | 37 +++- revert/remove_collection@v3.sql | 7 + revert/update_expense_payment_status.sql | 48 ++++- revert/update_expense_payment_status@v3.sql | 7 + revert/update_invoice_collection_status.sql | 46 ++++- .../update_invoice_collection_status@v3.sql | 7 + sqitch.plan | 11 ++ test/add_collection.sql | 30 ++- test/add_payment.sql | 36 +++- test/attach_to_collection.sql | 10 +- test/collection.sql | 187 ------------------ test/collection_attachment.sql | 131 ------------ test/edit_collection.sql | 35 +++- test/edit_payment.sql | 50 +++-- ...ice_collection.sql => invoice_payment.sql} | 66 +++---- test/payment.sql | 10 +- test/remove_collection.sql | 18 +- test/remove_payment.sql | 10 +- verify/_merge_collection_into_payment.sql | 7 + verify/add_collection@v3.sql | 7 + verify/add_payment@v3.sql | 7 + verify/attach_to_collection@v3.sql | 7 + verify/edit_collection@v3.sql | 7 + verify/edit_payment@v3.sql | 7 + verify/invoice_payment.sql | 13 ++ verify/remove_collection@v3.sql | 7 + verify/update_expense_payment_status@v3.sql | 7 + .../update_invoice_collection_status@v3.sql | 7 + web/template/payments/index.gohtml | 2 +- 62 files changed, 1361 insertions(+), 534 deletions(-) create mode 100644 deploy/_merge_collection_into_payment.sql create mode 100644 deploy/add_collection@v3.sql create mode 100644 deploy/add_payment@v3.sql create mode 100644 deploy/attach_to_collection@v3.sql create mode 100644 deploy/edit_collection@v3.sql create mode 100644 deploy/edit_payment@v3.sql create mode 100644 deploy/invoice_payment.sql create mode 100644 deploy/remove_collection@v3.sql create mode 100644 deploy/update_expense_payment_status@v3.sql create mode 100644 deploy/update_invoice_collection_status@v3.sql create mode 100644 revert/_merge_collection_into_payment.sql create mode 100644 revert/add_collection@v3.sql create mode 100644 revert/add_payment@v3.sql create mode 100644 revert/attach_to_collection@v3.sql create mode 100644 revert/edit_collection@v3.sql create mode 100644 revert/edit_payment@v3.sql create mode 100644 revert/invoice_payment.sql create mode 100644 revert/remove_collection@v3.sql create mode 100644 revert/update_expense_payment_status@v3.sql create mode 100644 revert/update_invoice_collection_status@v3.sql delete mode 100644 test/collection.sql delete mode 100644 test/collection_attachment.sql rename test/{invoice_collection.sql => invoice_payment.sql} (63%) create mode 100644 verify/_merge_collection_into_payment.sql create mode 100644 verify/add_collection@v3.sql create mode 100644 verify/add_payment@v3.sql create mode 100644 verify/attach_to_collection@v3.sql create mode 100644 verify/edit_collection@v3.sql create mode 100644 verify/edit_payment@v3.sql create mode 100644 verify/invoice_payment.sql create mode 100644 verify/remove_collection@v3.sql create mode 100644 verify/update_expense_payment_status@v3.sql create mode 100644 verify/update_invoice_collection_status@v3.sql diff --git a/deploy/_merge_collection_into_payment.sql b/deploy/_merge_collection_into_payment.sql new file mode 100644 index 0000000..6122126 --- /dev/null +++ b/deploy/_merge_collection_into_payment.sql @@ -0,0 +1,45 @@ +-- Deploy numerus:_merge_collection_into_payment to pg +-- requires: collection +-- requires: collection_attachment +-- requires: invoice_collection +-- requires: payment + +begin; + +set search_path to numerus, public; + +alter table payment + drop constraint if exists payment_amount_positive +, add constraint payment_amount_not_zero check (amount <> 0) +; + +update payment +set amount = -amount +; + +insert into payment (company_id, slug, description, payment_date, payment_account_id, amount, currency_code, tags, payment_status, created_at) +select company_id, slug, description, collection_date, payment_account_id, amount, currency_code, tags, payment_status, created_at +from collection +; + +insert into payment_attachment (payment_id, original_filename, mime_type, content) +select payment_id, original_filename, mime_type, content +from collection_attachment +join collection using (collection_id) +join payment using (slug) +; + +drop table collection_attachment; + +insert into invoice_payment (invoice_id, payment_id) +select invoice_id, payment_id +from invoice_collection +join collection using (collection_id) +join payment using (slug) +; + +drop table invoice_collection; + +drop table collection; + +commit; diff --git a/deploy/add_collection.sql b/deploy/add_collection.sql index b0a3cb6..3636331 100644 --- a/deploy/add_collection.sql +++ b/deploy/add_collection.sql @@ -1,8 +1,8 @@ -- Deploy numerus:add_collection to pg -- requires: roles -- requires: schema_numerus --- requires: collection --- requires: invoice_collection +-- requires: payment +-- requires: invoice_payment -- requires: company -- requires: currency -- requires: parse_price @@ -20,11 +20,11 @@ declare cslug uuid; amount_cents integer; begin - insert into collection + insert into payment ( company_id , payment_account_id , description - , collection_date + , payment_date , amount , currency_code , payment_status @@ -41,14 +41,14 @@ begin from company join currency using (currency_code) where company.company_id = add_collection.company - returning collection_id, slug, collection.amount + returning payment_id, slug, payment.amount into cid, cslug, amount_cents ; if invoice_id is not null then -- must be inserted before updating statuses, so that it can see this -- collection’s amount too. - insert into invoice_collection (invoice_id, collection_id) + insert into invoice_payment (invoice_id, payment_id) values (invoice_id, cid) ; diff --git a/deploy/add_collection@v3.sql b/deploy/add_collection@v3.sql new file mode 100644 index 0000000..b0a3cb6 --- /dev/null +++ b/deploy/add_collection@v3.sql @@ -0,0 +1,68 @@ +-- Deploy numerus:add_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: collection +-- requires: invoice_collection +-- requires: company +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_invoice_collection_status + +begin; + +set search_path to numerus, public; + +create or replace function add_collection(company integer, invoice_id integer, collection_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + cid integer; + cslug uuid; + amount_cents integer; +begin + insert into collection + ( company_id + , payment_account_id + , description + , collection_date + , amount + , currency_code + , payment_status + , tags + ) + select company_id + , payment_account_id + , description + , collection_date + , parse_price(amount, currency.decimal_digits) + , currency_code + , 'complete' + , tags + from company + join currency using (currency_code) + where company.company_id = add_collection.company + returning collection_id, slug, collection.amount + into cid, cslug, amount_cents + ; + + if invoice_id is not null then + -- must be inserted before updating statuses, so that it can see this + -- collection’s amount too. + insert into invoice_collection (invoice_id, collection_id) + values (invoice_id, cid) + ; + + perform update_invoice_collection_status(cid, invoice_id, amount_cents); + end if; + + return cslug; +end +$$ + language plpgsql +; + +revoke execute on function add_collection(integer, integer, date, integer, text, text, tag_name[]) from public; +grant execute on function add_collection(integer, integer, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function add_collection(integer, integer, date, integer, text, text, tag_name[]) to admin; + +commit; diff --git a/deploy/add_payment.sql b/deploy/add_payment.sql index 7e8ce03..08dd732 100644 --- a/deploy/add_payment.sql +++ b/deploy/add_payment.sql @@ -34,7 +34,7 @@ begin , payment_account_id , description , payment_date - , parse_price(amount, currency.decimal_digits) + , -parse_price(amount, currency.decimal_digits) , currency_code , 'complete' , tags diff --git a/deploy/add_payment@v3.sql b/deploy/add_payment@v3.sql new file mode 100644 index 0000000..7e8ce03 --- /dev/null +++ b/deploy/add_payment@v3.sql @@ -0,0 +1,67 @@ +-- Deploy numerus:add_payment to pg +-- requires: roles +-- requires: schema_numerus +-- requires: payment +-- requires: expense_payment +-- requires: company +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_expense_payment_status + +begin; + +set search_path to numerus, public; + +create or replace function add_payment(company integer, expense_id integer, payment_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + pslug uuid; + pid integer; + amount_cents integer; +begin + insert into payment + ( company_id + , payment_account_id + , description + , payment_date + , amount + , currency_code + , payment_status + , tags + ) + select company_id + , payment_account_id + , description + , payment_date + , parse_price(amount, currency.decimal_digits) + , currency_code + , 'complete' + , tags + from company + join currency using (currency_code) + where company.company_id = add_payment.company + returning payment_id, slug, payment.amount + into pid, pslug, amount_cents + ; + + if expense_id is not null then + -- must be inserted before updating statuses, so that it can see this + -- payment’s amount too. + insert into expense_payment (expense_id, payment_id) + values (expense_id, pid); + + perform update_expense_payment_status(pid, expense_id, amount_cents); + end if; + + return pslug; +end +$$ + language plpgsql +; + +revoke execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) from public; +grant execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) to admin; + +commit; diff --git a/deploy/attach_to_collection.sql b/deploy/attach_to_collection.sql index 3d97236..fa2ac2d 100644 --- a/deploy/attach_to_collection.sql +++ b/deploy/attach_to_collection.sql @@ -1,8 +1,6 @@ -- Deploy numerus:attach_to_collection to pg -- requires: roles --- requires: schema_numerus --- requires: collection --- requires: collection_attachment +-- requires: attach_to_payment begin; @@ -10,15 +8,7 @@ set search_path to numerus, public; create or replace function attach_to_collection(collection_slug uuid, original_filename text, mime_type text, content bytea) returns void as $$ - insert into collection_attachment (collection_id, original_filename, mime_type, content) - select collection_id, original_filename, mime_type, content - from collection - where slug = collection_slug - on conflict (collection_id) do update - set original_filename = excluded.original_filename - , mime_type = excluded.mime_type - , content = excluded.content - ; + select attach_to_payment(collection_slug, original_filename, mime_type, content); $$ language sql ; diff --git a/deploy/attach_to_collection@v3.sql b/deploy/attach_to_collection@v3.sql new file mode 100644 index 0000000..3d97236 --- /dev/null +++ b/deploy/attach_to_collection@v3.sql @@ -0,0 +1,30 @@ +-- Deploy numerus:attach_to_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: collection +-- requires: collection_attachment + +begin; + +set search_path to numerus, public; + +create or replace function attach_to_collection(collection_slug uuid, original_filename text, mime_type text, content bytea) returns void as +$$ + insert into collection_attachment (collection_id, original_filename, mime_type, content) + select collection_id, original_filename, mime_type, content + from collection + where slug = collection_slug + on conflict (collection_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_collection(uuid, text, text, bytea) from public; +grant execute on function attach_to_collection(uuid, text, text, bytea) to invoicer; +grant execute on function attach_to_collection(uuid, text, text, bytea) to admin; + +commit; diff --git a/deploy/edit_collection.sql b/deploy/edit_collection.sql index 5438f40..fe51880 100644 --- a/deploy/edit_collection.sql +++ b/deploy/edit_collection.sql @@ -1,8 +1,8 @@ -- Deploy numerus:edit_collection to pg -- requires: roles -- requires: schema_numerus --- requires: collection --- requires: invoice_collection +-- requires: payment +-- requires: invoice_payment -- requires: currency -- requires: parse_price -- requires: tag_name @@ -19,22 +19,22 @@ declare iid integer; amount_cents integer; begin - update collection - set collection_date = edit_collection.collection_date + update payment + set payment_date = edit_collection.collection_date , payment_account_id = edit_collection.payment_account_id , description = edit_collection.description , amount = parse_price(edit_collection.amount, decimal_digits) , tags = edit_collection.tags from currency where slug = collection_slug - and currency.currency_code = collection.currency_code - returning collection_id, collection.amount + and currency.currency_code = payment.currency_code + returning payment_id, payment.amount into cid, amount_cents ; select invoice_id into iid - from invoice_collection - where collection_id = cid; + from invoice_payment + where payment_id = cid; if iid is not null then perform update_invoice_collection_status(cid, iid, amount_cents); diff --git a/deploy/edit_collection@v3.sql b/deploy/edit_collection@v3.sql new file mode 100644 index 0000000..5438f40 --- /dev/null +++ b/deploy/edit_collection@v3.sql @@ -0,0 +1,53 @@ +-- Deploy numerus:edit_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: collection +-- requires: invoice_collection +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_invoice_collection_status + +begin; + +set search_path to numerus, public; + +create or replace function edit_collection(collection_slug uuid, collection_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + cid integer; + iid integer; + amount_cents integer; +begin + update collection + set collection_date = edit_collection.collection_date + , payment_account_id = edit_collection.payment_account_id + , description = edit_collection.description + , amount = parse_price(edit_collection.amount, decimal_digits) + , tags = edit_collection.tags + from currency + where slug = collection_slug + and currency.currency_code = collection.currency_code + returning collection_id, collection.amount + into cid, amount_cents + ; + + select invoice_id into iid + from invoice_collection + where collection_id = cid; + + if iid is not null then + perform update_invoice_collection_status(cid, iid, amount_cents); + end if; + + return collection_slug; +end +$$ + language plpgsql +; + +revoke execute on function edit_collection(uuid, date, integer, text, text, tag_name[]) from public; +grant execute on function edit_collection(uuid, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function edit_collection(uuid, date, integer, text, text, tag_name[]) to admin; + +commit; diff --git a/deploy/edit_payment.sql b/deploy/edit_payment.sql index 8d706f1..abdd522 100644 --- a/deploy/edit_payment.sql +++ b/deploy/edit_payment.sql @@ -23,7 +23,7 @@ begin set payment_date = edit_payment.payment_date , payment_account_id = edit_payment.payment_account_id , description = edit_payment.description - , amount = parse_price(edit_payment.amount, decimal_digits) + , amount = -parse_price(edit_payment.amount, decimal_digits) , tags = edit_payment.tags from currency where slug = payment_slug diff --git a/deploy/edit_payment@v3.sql b/deploy/edit_payment@v3.sql new file mode 100644 index 0000000..8d706f1 --- /dev/null +++ b/deploy/edit_payment@v3.sql @@ -0,0 +1,53 @@ +-- Deploy numerus:edit_payment to pg +-- requires: roles +-- requires: schema_numerus +-- requires: payment +-- requires: expense_payment +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_expense_payment_status + +begin; + +set search_path to numerus, public; + +create or replace function edit_payment(payment_slug uuid, payment_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + pid integer; + eid integer; + amount_cents integer; +begin + update payment + set payment_date = edit_payment.payment_date + , payment_account_id = edit_payment.payment_account_id + , description = edit_payment.description + , amount = parse_price(edit_payment.amount, decimal_digits) + , tags = edit_payment.tags + from currency + where slug = payment_slug + and currency.currency_code = payment.currency_code + returning payment_id, payment.amount + into pid, amount_cents + ; + + select expense_id into eid + from expense_payment + where payment_id = pid; + + if eid is not null then + perform update_expense_payment_status(pid, eid, amount_cents); + end if; + + return payment_slug; +end +$$ + language plpgsql +; + +revoke execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) from public; +grant execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) to admin; + +commit; diff --git a/deploy/invoice_payment.sql b/deploy/invoice_payment.sql new file mode 100644 index 0000000..bcbf887 --- /dev/null +++ b/deploy/invoice_payment.sql @@ -0,0 +1,32 @@ +-- Deploy numerus:invoice_payment to pg +-- requires: roles +-- requires: schema_numerus +-- requires: invoice +-- requires: payment + +begin; + +set search_path to numerus, public; + +create table invoice_payment ( + invoice_id integer not null references invoice, + payment_id integer not null references payment, + primary key (invoice_id, payment_id) +); + +grant select, insert, update, delete on table invoice_payment to invoicer; +grant select, insert, update, delete on table invoice_payment to admin; + +alter table invoice_payment enable row level security; + +create policy company_policy +on invoice_payment +using ( + exists( + select 1 + from invoice + where invoice.invoice_id = invoice_payment.invoice_id + ) +); + +commit; diff --git a/deploy/remove_collection.sql b/deploy/remove_collection.sql index 92225a0..e5848cc 100644 --- a/deploy/remove_collection.sql +++ b/deploy/remove_collection.sql @@ -1,9 +1,9 @@ -- Deploy numerus:remove_collection to pg -- requires: roles -- requires: schema_numerus --- requires: invoice_collection --- requires: collection --- requires: collection_attachment +-- requires: invoice_payment +-- requires: payment +-- requires: payment_attachment -- requires: update_invoice_collection_status begin; @@ -16,18 +16,18 @@ declare cid integer; iid integer; begin - select collection_id into cid from collection where slug = collection_slug; + select payment_id into cid from payment where slug = collection_slug; if not found then return; end if; - delete from invoice_collection where collection_id = cid returning invoice_id into iid; + delete from invoice_payment where payment_id = cid returning invoice_id into iid; if iid is not null then perform update_invoice_collection_status(null, iid, 0); end if; - delete from collection_attachment where collection_id = cid; - delete from collection where collection_id = cid; + delete from payment_attachment where payment_id = cid; + delete from payment where payment_id = cid; end $$ language plpgsql diff --git a/deploy/remove_collection@v3.sql b/deploy/remove_collection@v3.sql new file mode 100644 index 0000000..92225a0 --- /dev/null +++ b/deploy/remove_collection@v3.sql @@ -0,0 +1,40 @@ +-- Deploy numerus:remove_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: invoice_collection +-- requires: collection +-- requires: collection_attachment +-- requires: update_invoice_collection_status + +begin; + +set search_path to numerus, public; + +create or replace function remove_collection(collection_slug uuid) returns void as +$$ +declare + cid integer; + iid integer; +begin + select collection_id into cid from collection where slug = collection_slug; + if not found then + return; + end if; + + delete from invoice_collection where collection_id = cid returning invoice_id into iid; + if iid is not null then + perform update_invoice_collection_status(null, iid, 0); + end if; + + delete from collection_attachment where collection_id = cid; + delete from collection where collection_id = cid; +end +$$ + language plpgsql +; + +revoke execute on function remove_collection(uuid) from public; +grant execute on function remove_collection(uuid) to invoicer; +grant execute on function remove_collection(uuid) to admin; + +commit; diff --git a/deploy/update_expense_payment_status.sql b/deploy/update_expense_payment_status.sql index d73a892..d5ef784 100644 --- a/deploy/update_expense_payment_status.sql +++ b/deploy/update_expense_payment_status.sql @@ -15,7 +15,9 @@ set search_path to numerus, public; create or replace function update_expense_payment_status(pid integer, eid integer, amount_cents integer) returns void as $$ update payment - set payment_status = case when expense.amount + coalesce(tax.amount, 0) > amount_cents or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' else 'complete' end + set payment_status = case + when (expense.amount > 0 and expense.amount + coalesce(tax.amount, 0) > -amount_cents) or (expense.amount < 0 and expense.amount + coalesce(tax.amount, 0) < -amount_cents) or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' + else 'complete' end from expense left join ( select expense_id, sum(amount) as amount from expense_tax_amount group by expense_id) as tax using (expense_id) where expense.expense_id = eid @@ -24,7 +26,7 @@ $$ update expense set expense_status = case - when paid_amount >= expense.amount + tax_amount then 'paid' + when (expense.amount > 0 and -paid_amount >= expense.amount + tax_amount) or (expense.amount < 0 and -paid_amount <= expense.amount + tax_amount) then 'paid' when paid_amount = 0 then 'pending' else 'partial' end from ( diff --git a/deploy/update_expense_payment_status@v3.sql b/deploy/update_expense_payment_status@v3.sql new file mode 100644 index 0000000..d73a892 --- /dev/null +++ b/deploy/update_expense_payment_status@v3.sql @@ -0,0 +1,51 @@ +-- Deploy numerus:update_expense_payment_status to pg +-- requires: roles +-- requires: schema_numerus +-- requires: expense +-- requires: payment +-- requires: expense_payment +-- requires: expense_tax_amount +-- requires: available_expense_status +-- requires: available_payment_status + +begin; + +set search_path to numerus, public; + +create or replace function update_expense_payment_status(pid integer, eid integer, amount_cents integer) returns void as +$$ + update payment + set payment_status = case when expense.amount + coalesce(tax.amount, 0) > amount_cents or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' else 'complete' end + from expense + left join ( select expense_id, sum(amount) as amount from expense_tax_amount group by expense_id) as tax using (expense_id) + where expense.expense_id = eid + and payment_id = pid + ; + + update expense + set expense_status = case + when paid_amount >= expense.amount + tax_amount then 'paid' + when paid_amount = 0 then 'pending' + else 'partial' end + from ( + select coalesce (sum(payment.amount), 0) as paid_amount + from expense_payment + join payment using (payment_id) + where expense_payment.expense_id = eid + ) as payment, + ( + select coalesce (sum(amount), 0) as tax_amount + from expense_tax_amount + where expense_id = eid + ) as tax + where expense.expense_id = eid + ; +$$ + language sql +; + +revoke execute on function update_expense_payment_status(integer, integer, integer) from public; +grant execute on function update_expense_payment_status(integer, integer, integer) to invoicer; +grant execute on function update_expense_payment_status(integer, integer, integer) to admin; + +commit; diff --git a/deploy/update_invoice_collection_status.sql b/deploy/update_invoice_collection_status.sql index ddd5ec1..3f477a3 100644 --- a/deploy/update_invoice_collection_status.sql +++ b/deploy/update_invoice_collection_status.sql @@ -2,8 +2,8 @@ -- requires: roles -- requires: schema_numerus -- requires: invoice --- requires: collection --- requires: invoice_collection +-- requires: payment +-- requires: invoice_payment -- requires: invoice_amount -- requires: available_invoice_status -- requires: available_payment_status @@ -14,23 +14,25 @@ set search_path to numerus, public; create or replace function update_invoice_collection_status(cid integer, iid integer, amount_cents integer) returns void as $$ - update collection - set payment_status = case when invoice_amount.total > amount_cents or exists (select 1 from invoice_collection as ic where ic.collection_id = invoice_amount.invoice_id and collection_id <> cid) then 'partial' else 'complete' end + update payment + set payment_status = case + when (invoice_amount.total > 0 and invoice_amount.total > amount_cents) or (invoice_amount.total < 0 and invoice_amount.total < amount_cents) or exists (select 1 from invoice_payment as ic where ic.invoice_id = invoice_amount.invoice_id and payment_id <> cid) then 'partial' + else 'complete' end from invoice_amount where invoice_id = iid - and collection_id = cid + and payment_id = cid ; update invoice set invoice_status = case - when collected_amount >= total_amount then 'paid' + when (total_amount > 0 and collected_amount >= total_amount) or (total_amount < 0 and collected_amount <= total_amount) then 'paid' when collected_amount = 0 then 'created' else 'partial' end from ( - select coalesce(sum(collection.amount), 0) as collected_amount - from invoice_collection - join collection using (collection_id) - where invoice_collection.invoice_id = iid + select coalesce(sum(payment.amount), 0) as collected_amount + from invoice_payment + join payment using (payment_id) + where invoice_payment.invoice_id = iid ) as collection, ( select total as total_amount diff --git a/deploy/update_invoice_collection_status@v3.sql b/deploy/update_invoice_collection_status@v3.sql new file mode 100644 index 0000000..ddd5ec1 --- /dev/null +++ b/deploy/update_invoice_collection_status@v3.sql @@ -0,0 +1,49 @@ +-- Deploy numerus:update_invoice_collection_status to pg +-- requires: roles +-- requires: schema_numerus +-- requires: invoice +-- requires: collection +-- requires: invoice_collection +-- requires: invoice_amount +-- requires: available_invoice_status +-- requires: available_payment_status + +begin; + +set search_path to numerus, public; + +create or replace function update_invoice_collection_status(cid integer, iid integer, amount_cents integer) returns void as +$$ + update collection + set payment_status = case when invoice_amount.total > amount_cents or exists (select 1 from invoice_collection as ic where ic.collection_id = invoice_amount.invoice_id and collection_id <> cid) then 'partial' else 'complete' end + from invoice_amount + where invoice_id = iid + and collection_id = cid + ; + + update invoice + set invoice_status = case + when collected_amount >= total_amount then 'paid' + when collected_amount = 0 then 'created' + else 'partial' end + from ( + select coalesce(sum(collection.amount), 0) as collected_amount + from invoice_collection + join collection using (collection_id) + where invoice_collection.invoice_id = iid + ) as collection, + ( + select total as total_amount + from invoice_amount + where invoice_id = iid + ) as amount + where invoice.invoice_id = iid; +$$ + language sql +; + +revoke execute on function update_invoice_collection_status(integer, integer, integer) from public; +grant execute on function update_invoice_collection_status(integer, integer, integer) to invoicer; +grant execute on function update_invoice_collection_status(integer, integer, integer) to admin; + +commit; diff --git a/pkg/expenses.go b/pkg/expenses.go index 25ced60..810658b 100644 --- a/pkg/expenses.go +++ b/pkg/expenses.go @@ -321,7 +321,6 @@ func newExpenseForm(ctx context.Context, conn *Conn, locale *Locale, company *Co Required: true, Attributes: []template.HTMLAttr{ triggerRecompute, - `min="0"`, template.HTMLAttr(fmt.Sprintf(`step="%v"`, company.MinCents())), }, }, @@ -370,7 +369,7 @@ func (form *expenseForm) Validate() bool { validator.CheckValidSelectOption(form.Tax, gettext("Selected tax is not valid.", form.locale)) validator.CheckAtMostOneOfEachGroup(form.Tax, gettext("You can only select a tax of each class.", form.locale)) if validator.CheckRequiredInput(form.Amount, gettext("Amount can not be empty.", form.locale)) { - validator.CheckValidDecimal(form.Amount, form.company.MinCents(), math.MaxFloat64, gettext("Amount must be a number greater than zero.", form.locale)) + validator.CheckValidDecimal(form.Amount, -math.MaxFloat64, math.MaxFloat64, gettext("Amount must be a decimal number.", form.locale)) } return validator.AllOK() } diff --git a/pkg/invoices.go b/pkg/invoices.go index a07424b..be7d273 100644 --- a/pkg/invoices.go +++ b/pkg/invoices.go @@ -815,9 +815,9 @@ func mustCollectInvoiceEntriesLastCollectionDate(ctx context.Context, conn *Conn }) return mustMakeDateMap(ctx, conn, ids, ` select invoice_id - , max(collection_date) - from invoice_collection - join collection using (collection_id) + , max(payment_date) + from invoice_payment + join payment using (payment_id) where invoice_id = any ($1) group by invoice_id `) diff --git a/pkg/payments.go b/pkg/payments.go index 1f43487..534e52a 100644 --- a/pkg/payments.go +++ b/pkg/payments.go @@ -121,7 +121,7 @@ func (expense *PaymentExpense) BaseURI(company *Company) string { func (expense *PaymentExpense) calcRemainingPaymentAmount(ctx context.Context, conn *Conn) string { return conn.MustGetText(ctx, "", ` - select to_price(greatest(0, expense.amount + tax_amount - paid_amount)::int, decimal_digits) + select to_price((expense.amount + tax_amount - paid_amount)::int, decimal_digits) from ( select coalesce (sum(payment.amount), 0) as paid_amount from expense_payment @@ -175,12 +175,12 @@ func (invoice *CollectionInvoice) BaseURI(company *Company) string { func (invoice *CollectionInvoice) calcRemainingPaymentAmount(ctx context.Context, conn *Conn) string { return conn.MustGetText(ctx, "", ` - select to_price(greatest(0, invoice_amount.total - collected_amount)::int, decimal_digits) + select to_price((invoice_amount.total - collected_amount)::int, decimal_digits) from ( - select coalesce (sum(collection.amount), 0) as collected_amount - from invoice_collection - join collection using (collection_id) - where invoice_collection.invoice_id = $1 + select coalesce (sum(payment.amount), 0) as collected_amount + from invoice_payment + join payment using (payment_id) + where invoice_payment.invoice_id = $1 ) as collection cross join ( select total @@ -210,7 +210,7 @@ type PaymentEntry struct { func mustCollectPaymentEntries(ctx context.Context, conn *Conn, company *Company, locale *Locale, paymentType string, documentId int) []*PaymentEntry { rows := conn.MustQuery(ctx, ` - select $5 as type + select case when payment.amount < 0 then $5 else $6 end as type , payment_id , payment.slug , payment_date @@ -220,37 +220,18 @@ func mustCollectPaymentEntries(ctx context.Context, conn *Conn, company *Company , payment.payment_status , psi18n.name , coalesce(attachment.original_filename, '') - , coalesce(expense.slug::text, '') - , coalesce(expense.invoice_number, '') + , coalesce(expense.slug::text, invoice.slug::text, '') + , coalesce(expense.invoice_number, invoice.invoice_number, '') from payment join payment_status_i18n psi18n on payment.payment_status = psi18n.payment_status and psi18n.lang_tag = $1 join currency using (currency_code) left join payment_attachment as attachment using (payment_id) left join expense_payment using (payment_id) left join expense using (expense_id) - where payment.company_id = $2 - and ($3 = '' or ($3 = $5 and expense_id = $4)) - union all - select $6 as type - , collection_id - , collection.slug - , collection_date as payment_date - , description - , to_price(collection.amount, decimal_digits) as total - , collection.tags - , collection.payment_status - , psi18n.name - , coalesce(attachment.original_filename, '') - , coalesce(invoice.slug::text, '') - , coalesce(invoice.invoice_number, '') - from collection - join payment_status_i18n psi18n on collection.payment_status = psi18n.payment_status and psi18n.lang_tag = $1 - join currency using (currency_code) - left join collection_attachment as attachment using (collection_id) - left join invoice_collection using (collection_id) + left join invoice_payment using (payment_id) left join invoice using (invoice_id) - where collection.company_id = $2 - and ($3 = '' or ($3 = $6 and invoice_id = $4)) + where payment.company_id = $2 + and ($3 = '' or ($3 = $5 and expense_id = $4) or ($3 = $6 and invoice_id = $4)) order by payment_date desc, total desc `, locale.Language, company.Id, paymentType, documentId, PaymentTypePayment, PaymentTypeCollection) defer rows.Close() @@ -406,7 +387,6 @@ func newPaymentForm(ctx context.Context, conn *Conn, locale *Locale, company *Co Type: "number", Required: true, Attributes: []template.HTMLAttr{ - `min="0"`, template.HTMLAttr(fmt.Sprintf(`step="%v"`, company.MinCents())), }, }, @@ -453,7 +433,7 @@ func (f *PaymentForm) MustFillFromDatabase(ctx context.Context, conn *Conn, slug selectedPaymentAccount := f.PaymentAccount.Selected f.PaymentAccount.Clear() if notFoundErrorOrPanic(conn.QueryRow(ctx, ` - select $2 as type + select case when amount < 0 then $2 else $3 end as type , description , payment_date , payment_account_id::text @@ -462,16 +442,6 @@ func (f *PaymentForm) MustFillFromDatabase(ctx context.Context, conn *Conn, slug from payment join currency using (currency_code) where payment.slug = $1 - union all - select $3 as type - , description - , collection_date - , payment_account_id::text - , to_price(amount, decimal_digits) - , tags - from collection - join currency using (currency_code) - where collection.slug = $1 `, slug, PaymentTypePayment, PaymentTypeCollection).Scan( f.Type, f.Description, @@ -510,7 +480,7 @@ func (f *PaymentForm) Validate() bool { validator.CheckValidSelectOption(f.PaymentAccount, gettext("Selected payment account is not valid.", f.locale)) validator.CheckValidDate(f.PaymentDate, gettext("Payment date must be a valid date.", f.locale)) if validator.CheckRequiredInput(f.Amount, gettext("Amount can not be empty.", f.locale)) { - validator.CheckValidDecimal(f.Amount, f.company.MinCents(), math.MaxFloat64, gettext("Amount must be a number greater than zero.", f.locale)) + validator.CheckValidDecimal(f.Amount, -math.MaxFloat64, math.MaxFloat64, gettext("Amount must be a decimal number.", f.locale)) } return validator.AllOK() } @@ -721,19 +691,13 @@ func servePaymentAttachment(w http.ResponseWriter, r *http.Request, params httpr from payment join payment_attachment using (payment_id) where slug = $1 - union all - select mime_type - , content - from collection - join collection_attachment using (collection_id) - where slug = $1 `) } func servePaymentTagsEditForm(w http.ResponseWriter, r *http.Request, params httprouter.Params) { - serveTagsEditForm(w, r, params, "/payments/", "select tags from payment where slug = $1 union all select tags from collection where slug = $1") + serveTagsEditForm(w, r, params, "/payments/", "select tags from payment where slug = $1") } func handleUpdatePaymentTags(w http.ResponseWriter, r *http.Request, params httprouter.Params) { - handleUpdateTags(w, r, params, "/payments/", "with p as (update payment set tags = $1 where slug = $2 returning slug), c as (update collection set tags = $1 where slug = $2 returning slug) select p.slug from p union all select c.slug from c") + handleUpdateTags(w, r, params, "/payments/", "update payment set tags = $1 where slug = $2 returning slug") } diff --git a/revert/_merge_collection_into_payment.sql b/revert/_merge_collection_into_payment.sql new file mode 100644 index 0000000..1ec5b47 --- /dev/null +++ b/revert/_merge_collection_into_payment.sql @@ -0,0 +1,120 @@ +-- Revert numerus:_merge_collection_into_payment from pg + +begin; + +set search_path to numerus, public; + + +create table collection ( + collection_id integer generated by default as identity primary key, + company_id integer not null references company, + slug uuid not null unique default gen_random_uuid(), + description text not null, + collection_date date not null default current_date, + payment_account_id integer not null references payment_account, + amount integer not null constraint collection_amount_positive check (amount > 0), + currency_code text not null references currency, + tags tag_name[] not null default '{}', + payment_status text not null default 'complete' references payment_status, + created_at timestamptz not null default current_timestamp +); + +grant select, insert, update, delete on table collection to invoicer; +grant select, insert, update, delete on table collection to admin; + +alter table collection enable row level security; + +create policy company_policy +on collection +using ( + exists( + select 1 + from company_user + join user_profile using (user_id) + where company_user.company_id = collection.company_id + ) +); + +insert into collection (company_id, slug, description, collection_date, payment_account_id, amount, currency_code, tags, payment_status, created_at) +select company_id, slug, description, payment_date, payment_account_id, amount, currency_code, tags, payment_status, created_at +from payment +where amount > 0 +; + +create table invoice_collection ( + invoice_id integer not null references invoice, + collection_id integer not null references collection, + primary key (invoice_id, collection_id) +); + +grant select, insert, update, delete on table invoice_collection to invoicer; +grant select, insert, update, delete on table invoice_collection to admin; + +alter table invoice_collection enable row level security; + +create policy company_policy +on invoice_collection +using ( + exists( + select 1 + from invoice + where invoice.invoice_id = invoice_collection.invoice_id + ) +); + +insert into invoice_collection (invoice_id, collection_id) +select invoice_id, collection_id +from invoice_payment +join payment using (payment_id) +join collection using (slug) +; + +delete from invoice_payment; + +create table collection_attachment ( + collection_id integer primary key references collection, + original_filename text not null, + mime_type text not null, + content bytea not null +); + +grant select, insert, update, delete on table collection_attachment to invoicer; +grant select, insert, update, delete on table collection_attachment to admin; + +alter table collection_attachment enable row level security; + +create policy company_policy +on collection_attachment +using ( + exists( + select 1 + from collection + where collection.collection_id = collection_attachment.collection_id + ) +); + +insert into collection_attachment (collection_id, original_filename, mime_type, content) +select collection_id, original_filename, mime_type, content +from payment_attachment +join payment using (payment_id) +join collection using (slug) +where payment.amount > 0 +; + +delete from payment_attachment +where payment_id in ( + select payment_id from payment where amount > 0 +); + +delete from payment where amount > 0; + +update payment +set amount = -amount +; + +alter table payment + add constraint payment_amount_positive check (amount > 0) +, drop constraint if exists payment_amount_not_zero +; + +commit; diff --git a/revert/add_collection.sql b/revert/add_collection.sql index 888f056..b0a3cb6 100644 --- a/revert/add_collection.sql +++ b/revert/add_collection.sql @@ -1,7 +1,68 @@ --- Revert numerus:add_collection from pg +-- Deploy numerus:add_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: collection +-- requires: invoice_collection +-- requires: company +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_invoice_collection_status begin; -drop function if exists numerus.add_collection(integer, integer, date, integer, text, text, numerus.tag_name[]); +set search_path to numerus, public; + +create or replace function add_collection(company integer, invoice_id integer, collection_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + cid integer; + cslug uuid; + amount_cents integer; +begin + insert into collection + ( company_id + , payment_account_id + , description + , collection_date + , amount + , currency_code + , payment_status + , tags + ) + select company_id + , payment_account_id + , description + , collection_date + , parse_price(amount, currency.decimal_digits) + , currency_code + , 'complete' + , tags + from company + join currency using (currency_code) + where company.company_id = add_collection.company + returning collection_id, slug, collection.amount + into cid, cslug, amount_cents + ; + + if invoice_id is not null then + -- must be inserted before updating statuses, so that it can see this + -- collection’s amount too. + insert into invoice_collection (invoice_id, collection_id) + values (invoice_id, cid) + ; + + perform update_invoice_collection_status(cid, invoice_id, amount_cents); + end if; + + return cslug; +end +$$ + language plpgsql +; + +revoke execute on function add_collection(integer, integer, date, integer, text, text, tag_name[]) from public; +grant execute on function add_collection(integer, integer, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function add_collection(integer, integer, date, integer, text, text, tag_name[]) to admin; commit; diff --git a/revert/add_collection@v3.sql b/revert/add_collection@v3.sql new file mode 100644 index 0000000..888f056 --- /dev/null +++ b/revert/add_collection@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:add_collection from pg + +begin; + +drop function if exists numerus.add_collection(integer, integer, date, integer, text, text, numerus.tag_name[]); + +commit; diff --git a/revert/add_payment.sql b/revert/add_payment.sql index 685198f..7e8ce03 100644 --- a/revert/add_payment.sql +++ b/revert/add_payment.sql @@ -1,7 +1,67 @@ --- Revert numerus:add_payment from pg +-- Deploy numerus:add_payment to pg +-- requires: roles +-- requires: schema_numerus +-- requires: payment +-- requires: expense_payment +-- requires: company +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_expense_payment_status begin; -drop function if exists numerus.add_payment(integer, integer, date, integer, text, text, numerus.tag_name[]); +set search_path to numerus, public; + +create or replace function add_payment(company integer, expense_id integer, payment_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + pslug uuid; + pid integer; + amount_cents integer; +begin + insert into payment + ( company_id + , payment_account_id + , description + , payment_date + , amount + , currency_code + , payment_status + , tags + ) + select company_id + , payment_account_id + , description + , payment_date + , parse_price(amount, currency.decimal_digits) + , currency_code + , 'complete' + , tags + from company + join currency using (currency_code) + where company.company_id = add_payment.company + returning payment_id, slug, payment.amount + into pid, pslug, amount_cents + ; + + if expense_id is not null then + -- must be inserted before updating statuses, so that it can see this + -- payment’s amount too. + insert into expense_payment (expense_id, payment_id) + values (expense_id, pid); + + perform update_expense_payment_status(pid, expense_id, amount_cents); + end if; + + return pslug; +end +$$ + language plpgsql +; + +revoke execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) from public; +grant execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) to admin; commit; diff --git a/revert/add_payment@v3.sql b/revert/add_payment@v3.sql new file mode 100644 index 0000000..685198f --- /dev/null +++ b/revert/add_payment@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:add_payment from pg + +begin; + +drop function if exists numerus.add_payment(integer, integer, date, integer, text, text, numerus.tag_name[]); + +commit; diff --git a/revert/attach_to_collection.sql b/revert/attach_to_collection.sql index 531e0a7..3d97236 100644 --- a/revert/attach_to_collection.sql +++ b/revert/attach_to_collection.sql @@ -1,7 +1,30 @@ --- Revert numerus:attach_to_collection from pg +-- Deploy numerus:attach_to_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: collection +-- requires: collection_attachment begin; -drop function if exists numerus.attach_to_collection(uuid, text, text, bytea); +set search_path to numerus, public; + +create or replace function attach_to_collection(collection_slug uuid, original_filename text, mime_type text, content bytea) returns void as +$$ + insert into collection_attachment (collection_id, original_filename, mime_type, content) + select collection_id, original_filename, mime_type, content + from collection + where slug = collection_slug + on conflict (collection_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_collection(uuid, text, text, bytea) from public; +grant execute on function attach_to_collection(uuid, text, text, bytea) to invoicer; +grant execute on function attach_to_collection(uuid, text, text, bytea) to admin; commit; diff --git a/revert/attach_to_collection@v3.sql b/revert/attach_to_collection@v3.sql new file mode 100644 index 0000000..531e0a7 --- /dev/null +++ b/revert/attach_to_collection@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:attach_to_collection from pg + +begin; + +drop function if exists numerus.attach_to_collection(uuid, text, text, bytea); + +commit; diff --git a/revert/edit_collection.sql b/revert/edit_collection.sql index 79487d1..5438f40 100644 --- a/revert/edit_collection.sql +++ b/revert/edit_collection.sql @@ -1,7 +1,53 @@ --- Revert numerus:edit_collection from pg +-- Deploy numerus:edit_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: collection +-- requires: invoice_collection +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_invoice_collection_status begin; -drop function if exists numerus.edit_collection(uuid, date, integer, text, text, numerus.tag_name[]); +set search_path to numerus, public; + +create or replace function edit_collection(collection_slug uuid, collection_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + cid integer; + iid integer; + amount_cents integer; +begin + update collection + set collection_date = edit_collection.collection_date + , payment_account_id = edit_collection.payment_account_id + , description = edit_collection.description + , amount = parse_price(edit_collection.amount, decimal_digits) + , tags = edit_collection.tags + from currency + where slug = collection_slug + and currency.currency_code = collection.currency_code + returning collection_id, collection.amount + into cid, amount_cents + ; + + select invoice_id into iid + from invoice_collection + where collection_id = cid; + + if iid is not null then + perform update_invoice_collection_status(cid, iid, amount_cents); + end if; + + return collection_slug; +end +$$ + language plpgsql +; + +revoke execute on function edit_collection(uuid, date, integer, text, text, tag_name[]) from public; +grant execute on function edit_collection(uuid, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function edit_collection(uuid, date, integer, text, text, tag_name[]) to admin; commit; diff --git a/revert/edit_collection@v3.sql b/revert/edit_collection@v3.sql new file mode 100644 index 0000000..79487d1 --- /dev/null +++ b/revert/edit_collection@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:edit_collection from pg + +begin; + +drop function if exists numerus.edit_collection(uuid, date, integer, text, text, numerus.tag_name[]); + +commit; diff --git a/revert/edit_payment.sql b/revert/edit_payment.sql index 93e9ae5..8d706f1 100644 --- a/revert/edit_payment.sql +++ b/revert/edit_payment.sql @@ -1,7 +1,53 @@ --- Revert numerus:edit_payment from pg +-- Deploy numerus:edit_payment to pg +-- requires: roles +-- requires: schema_numerus +-- requires: payment +-- requires: expense_payment +-- requires: currency +-- requires: parse_price +-- requires: tag_name +-- requires: update_expense_payment_status begin; -drop function if exists numerus.edit_payment(uuid, date, integer, text, text, numerus.tag_name[]); +set search_path to numerus, public; + +create or replace function edit_payment(payment_slug uuid, payment_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as +$$ +declare + pid integer; + eid integer; + amount_cents integer; +begin + update payment + set payment_date = edit_payment.payment_date + , payment_account_id = edit_payment.payment_account_id + , description = edit_payment.description + , amount = parse_price(edit_payment.amount, decimal_digits) + , tags = edit_payment.tags + from currency + where slug = payment_slug + and currency.currency_code = payment.currency_code + returning payment_id, payment.amount + into pid, amount_cents + ; + + select expense_id into eid + from expense_payment + where payment_id = pid; + + if eid is not null then + perform update_expense_payment_status(pid, eid, amount_cents); + end if; + + return payment_slug; +end +$$ + language plpgsql +; + +revoke execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) from public; +grant execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) to invoicer; +grant execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) to admin; commit; diff --git a/revert/edit_payment@v3.sql b/revert/edit_payment@v3.sql new file mode 100644 index 0000000..93e9ae5 --- /dev/null +++ b/revert/edit_payment@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:edit_payment from pg + +begin; + +drop function if exists numerus.edit_payment(uuid, date, integer, text, text, numerus.tag_name[]); + +commit; diff --git a/revert/invoice_payment.sql b/revert/invoice_payment.sql new file mode 100644 index 0000000..999d8d2 --- /dev/null +++ b/revert/invoice_payment.sql @@ -0,0 +1,7 @@ +-- Revert numerus:invoice_payment from pg + +begin; + +drop table if exists numerus.invoice_payment; + +commit; diff --git a/revert/remove_collection.sql b/revert/remove_collection.sql index aeff0bb..92225a0 100644 --- a/revert/remove_collection.sql +++ b/revert/remove_collection.sql @@ -1,7 +1,40 @@ --- Revert numerus:remove_collection from pg +-- Deploy numerus:remove_collection to pg +-- requires: roles +-- requires: schema_numerus +-- requires: invoice_collection +-- requires: collection +-- requires: collection_attachment +-- requires: update_invoice_collection_status begin; -drop function if exists numerus.remove_collection(uuid); +set search_path to numerus, public; + +create or replace function remove_collection(collection_slug uuid) returns void as +$$ +declare + cid integer; + iid integer; +begin + select collection_id into cid from collection where slug = collection_slug; + if not found then + return; + end if; + + delete from invoice_collection where collection_id = cid returning invoice_id into iid; + if iid is not null then + perform update_invoice_collection_status(null, iid, 0); + end if; + + delete from collection_attachment where collection_id = cid; + delete from collection where collection_id = cid; +end +$$ + language plpgsql +; + +revoke execute on function remove_collection(uuid) from public; +grant execute on function remove_collection(uuid) to invoicer; +grant execute on function remove_collection(uuid) to admin; commit; diff --git a/revert/remove_collection@v3.sql b/revert/remove_collection@v3.sql new file mode 100644 index 0000000..aeff0bb --- /dev/null +++ b/revert/remove_collection@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:remove_collection from pg + +begin; + +drop function if exists numerus.remove_collection(uuid); + +commit; diff --git a/revert/update_expense_payment_status.sql b/revert/update_expense_payment_status.sql index 381cf35..d73a892 100644 --- a/revert/update_expense_payment_status.sql +++ b/revert/update_expense_payment_status.sql @@ -1,7 +1,51 @@ --- Revert numerus:update_expense_payment_status from pg +-- Deploy numerus:update_expense_payment_status to pg +-- requires: roles +-- requires: schema_numerus +-- requires: expense +-- requires: payment +-- requires: expense_payment +-- requires: expense_tax_amount +-- requires: available_expense_status +-- requires: available_payment_status begin; -drop function if exists numerus.update_expense_payment_status(integer, integer, integer); +set search_path to numerus, public; + +create or replace function update_expense_payment_status(pid integer, eid integer, amount_cents integer) returns void as +$$ + update payment + set payment_status = case when expense.amount + coalesce(tax.amount, 0) > amount_cents or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' else 'complete' end + from expense + left join ( select expense_id, sum(amount) as amount from expense_tax_amount group by expense_id) as tax using (expense_id) + where expense.expense_id = eid + and payment_id = pid + ; + + update expense + set expense_status = case + when paid_amount >= expense.amount + tax_amount then 'paid' + when paid_amount = 0 then 'pending' + else 'partial' end + from ( + select coalesce (sum(payment.amount), 0) as paid_amount + from expense_payment + join payment using (payment_id) + where expense_payment.expense_id = eid + ) as payment, + ( + select coalesce (sum(amount), 0) as tax_amount + from expense_tax_amount + where expense_id = eid + ) as tax + where expense.expense_id = eid + ; +$$ + language sql +; + +revoke execute on function update_expense_payment_status(integer, integer, integer) from public; +grant execute on function update_expense_payment_status(integer, integer, integer) to invoicer; +grant execute on function update_expense_payment_status(integer, integer, integer) to admin; commit; diff --git a/revert/update_expense_payment_status@v3.sql b/revert/update_expense_payment_status@v3.sql new file mode 100644 index 0000000..381cf35 --- /dev/null +++ b/revert/update_expense_payment_status@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:update_expense_payment_status from pg + +begin; + +drop function if exists numerus.update_expense_payment_status(integer, integer, integer); + +commit; diff --git a/revert/update_invoice_collection_status.sql b/revert/update_invoice_collection_status.sql index 054243b..ddd5ec1 100644 --- a/revert/update_invoice_collection_status.sql +++ b/revert/update_invoice_collection_status.sql @@ -1,7 +1,49 @@ --- Revert numerus:update_invoice_collection_status from pg +-- Deploy numerus:update_invoice_collection_status to pg +-- requires: roles +-- requires: schema_numerus +-- requires: invoice +-- requires: collection +-- requires: invoice_collection +-- requires: invoice_amount +-- requires: available_invoice_status +-- requires: available_payment_status begin; -drop function if exists numerus.update_invoice_collection_status(integer, integer, integer); +set search_path to numerus, public; + +create or replace function update_invoice_collection_status(cid integer, iid integer, amount_cents integer) returns void as +$$ + update collection + set payment_status = case when invoice_amount.total > amount_cents or exists (select 1 from invoice_collection as ic where ic.collection_id = invoice_amount.invoice_id and collection_id <> cid) then 'partial' else 'complete' end + from invoice_amount + where invoice_id = iid + and collection_id = cid + ; + + update invoice + set invoice_status = case + when collected_amount >= total_amount then 'paid' + when collected_amount = 0 then 'created' + else 'partial' end + from ( + select coalesce(sum(collection.amount), 0) as collected_amount + from invoice_collection + join collection using (collection_id) + where invoice_collection.invoice_id = iid + ) as collection, + ( + select total as total_amount + from invoice_amount + where invoice_id = iid + ) as amount + where invoice.invoice_id = iid; +$$ + language sql +; + +revoke execute on function update_invoice_collection_status(integer, integer, integer) from public; +grant execute on function update_invoice_collection_status(integer, integer, integer) to invoicer; +grant execute on function update_invoice_collection_status(integer, integer, integer) to admin; commit; diff --git a/revert/update_invoice_collection_status@v3.sql b/revert/update_invoice_collection_status@v3.sql new file mode 100644 index 0000000..054243b --- /dev/null +++ b/revert/update_invoice_collection_status@v3.sql @@ -0,0 +1,7 @@ +-- Revert numerus:update_invoice_collection_status from pg + +begin; + +drop function if exists numerus.update_invoice_collection_status(integer, integer, integer); + +commit; diff --git a/sqitch.plan b/sqitch.plan index fc5c00c..9a94a01 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -169,3 +169,14 @@ remove_collection [roles schema_numerus invoice_collection collection collection edit_invoice [edit_invoice@v2] 2024-08-26T08:18:08Z jordi fita mas # Remove the invoice_status parameter from edit_invoice remove_expense [roles schema_numerus expense_tax expense_attachment expense] 2024-09-08T21:42:51Z jordi fita mas # Add function to remove expenses @v3 2025-01-30T10:39:55Z jordi fita mas # Tag version 3 + +invoice_payment [roles schema_numerus invoice payment] 2025-01-30T19:48:21Z jordi fita mas # Add relation of invoice payments +add_collection [add_collection@v3 payment invoice_payment] 2025-01-30T20:39:29Z jordi fita mas # Use payment and invoice_payment relations instead of collection and invoice_collection in add_collection +update_invoice_collection_status [update_invoice_collection_status@v3 payment invoice_payment] 2025-01-30T20:42:25Z jordi fita mas # Use payment relation, and take into account negative invoices, in update_invoice_collection_status +edit_collection [edit_collection@v3 payment invoice_payment] 2025-01-30T20:43:51Z jordi fita mas # Use payment and invoice_payment relations instead of collection and invoice_collection in edit_collection +attach_to_collection [attach_to_collection@v3 attach_to_payment] 2025-01-30T20:58:41Z jordi fita mas # Make attach_to_collection an alias of attach_to_payment +remove_collection [remove_collection@v3 payment invoice_payment payment_attachment] 2025-01-30T21:02:39Z jordi fita mas # Use payment, payment_attachment, and invoice_payment relations instead of collection, collection_attachment, and invoice_collection in remove_collection +add_payment [add_payment@v3] 2025-01-30T21:21:52Z jordi fita mas # Record expense as negative payments in add_payment +update_expense_payment_status [update_expense_payment_status@v3] 2025-01-30T21:24:02Z jordi fita mas # Take into account negative expenses in update_expense_payment_status +edit_payment [edit_payment@v3] 2025-01-30T21:46:29Z jordi fita mas # Record expense as negative payments in edit_payment +_merge_collection_into_payment [collection collection_attachment invoice_collection invoice_payment payment] 2025-01-30T19:44:39Z jordi fita mas # Subsume collection and their attachments as positive payments, while expenses are now negative payments diff --git a/test/add_collection.sql b/test/add_collection.sql index 73226d2..cc94430 100644 --- a/test/add_collection.sql +++ b/test/add_collection.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(20); +select plan(22); set search_path to numerus, auth, public; @@ -22,8 +22,8 @@ select function_privs_are('numerus', 'add_collection', array ['integer', 'intege set client_min_messages to warning; -truncate invoice_collection cascade; -truncate collection cascade; +truncate invoice_payment cascade; +truncate payment cascade; truncate payment_account cascade; truncate invoice_product_tax cascade; truncate invoice_product cascade; @@ -78,6 +78,8 @@ values (12, 1, 'REF123', 9, '2011-01-11', 111, 'EUR') , (16, 1, 'REF001', 9, '2023-03-03', 111, 'EUR') , (17, 1, 'REF002', 9, '2023-03-03', 111, 'EUR') , (18, 1, 'REF003', 9, '2023-03-03', 111, 'EUR') + , (19, 1, 'RET001', 9, '2023-03-03', 111, 'EUR') + , (20, 1, 'RET002', 9, '2023-03-03', 222, 'EUR') ; insert into invoice_product (invoice_product_id, invoice_id, name, price) @@ -93,6 +95,8 @@ values (19, 12, 'P1', 100) , (28, 16, 'P*', 10000) , (29, 17, 'P*', 10000) , (30, 18, 'P*', 10000) + , (31, 19, 'P*', -111) + , (32, 20, 'P*', -333) ; insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate) @@ -147,8 +151,18 @@ select lives_ok( 'Should be able to collect an invoice with multiple taxes' ); +select lives_ok( + $$ select add_collection(1, 19, '2023-03-07', 11, 'Re: RET001', '-1.11', array[]::tag_name[]) $$, + 'Should be able to collect a negative invoice (e.g., a refund)' +); + +select lives_ok( + $$ select add_collection(1, 20, '2023-03-08', 22, 'Re: RET002', '-1.11', array[]::tag_name[]) $$, + 'Should be able to partially collect a negative invoice (e.g., a refund)' +); + select bag_eq( - $$ select company_id, description, collection_date::text, payment_account_id, amount, currency_code, payment_status, tags::text, created_at from collection $$, + $$ select company_id, description, payment_date::text, payment_account_id, amount, currency_code, payment_status, tags::text, created_at from payment $$, $$ values (1, '“Protection”', '2023-05-02', 11, 1111, 'EUR', 'complete', '{tag1,tag2}', current_timestamp) , (2, 'Collection of INV001', '2023-05-03', 22, 111, 'USD', 'complete', '{}', current_timestamp) , (2, 'First collection of INV002', '2023-05-04', 22, 100, 'USD', 'partial', '{}', current_timestamp) @@ -157,12 +171,14 @@ select bag_eq( , (1, 'Re: REF001', '2023-03-06', 11, 10399, 'EUR', 'partial', '{}', current_timestamp) , (1, 'Re: REF002', '2023-03-06', 11, 8500, 'EUR', 'complete', '{}', current_timestamp) , (1, 'Re: REF003', '2023-03-06', 11, 9500, 'EUR', 'complete', '{}', current_timestamp) + , (1, 'Re: RET001', '2023-03-07', 11, -111, 'EUR', 'complete', '{}', current_timestamp) + , (1, 'Re: RET002', '2023-03-08', 22, -111, 'EUR', 'partial', '{}', current_timestamp) $$, 'Should have created all collections' ); select bag_eq( - $$ select invoice_id, description from invoice_collection join collection using (collection_id) $$, + $$ select invoice_id, description from invoice_payment join payment using (payment_id) $$, $$ values (13, 'Collection of INV001') , (14, 'First collection of INV002') , (14, 'Second collection of INV002') @@ -170,6 +186,8 @@ select bag_eq( , (16, 'Re: REF001') , (17, 'Re: REF002') , (18, 'Re: REF003') + , (19, 'Re: RET001') + , (20, 'Re: RET002') $$, 'Should have linked all invoices to collections' ); @@ -183,6 +201,8 @@ select bag_eq( , (16, 'partial') , (17, 'paid') , (18, 'paid') + , (19, 'paid') + , (20, 'partial') $$, 'Should have updated the status of invoices' ); diff --git a/test/add_payment.sql b/test/add_payment.sql index 5542389..edc40d4 100644 --- a/test/add_payment.sql +++ b/test/add_payment.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(20); +select plan(22); set search_path to numerus, auth, public; @@ -71,6 +71,8 @@ values (12, 1, 'REF123', 9, '2011-01-11', 111, 'EUR') , (16, 1, 'REF001', 9, '2023-03-03', 10000, 'EUR') , (17, 1, 'REF002', 9, '2023-03-03', 10000, 'EUR') , (18, 1, 'REF003', 9, '2023-03-03', 10000, 'EUR') + , (19, 1, 'RET001', 9, '2023-03-03', -111, 'EUR') + , (20, 1, 'RET002', 9, '2023-03-03', -333, 'EUR') ; insert into expense_tax (expense_id, tax_id, tax_rate) @@ -125,16 +127,28 @@ select lives_ok( 'Should be able to pay an expense with multiple taxes' ); +select lives_ok( + $$ select add_payment(1, 19, '2023-03-07', 11, 'Re: RET001', '-1.11', array[]::tag_name[]) $$, + 'Should be able to pay an negative expense (e.g., a refund)' +); + +select lives_ok( + $$ select add_payment(1, 20, '2023-03-08', 22, 'Re: RET002', '-1.11', array[]::tag_name[]) $$, + 'Should be able to partially pay an negative expense (e.g., a refund)' +); + select bag_eq( $$ select company_id, description, payment_date::text, payment_account_id, amount, currency_code, payment_status, tags::text, created_at from payment $$, - $$ values (1, '“Protection”', '2023-05-02', 11, 1111, 'EUR', 'complete', '{tag1,tag2}', current_timestamp) - , (2, 'Payment of INV001', '2023-05-03', 22, 111, 'USD', 'complete', '{}', current_timestamp) - , (2, 'First payment of INV002', '2023-05-04', 22, 100, 'USD', 'partial', '{}', current_timestamp) - , (2, 'Second payment of INV002', '2023-05-05', 22, 122, 'USD', 'partial', '{}', current_timestamp) - , (2, 'Partial payment of INV003', '2023-05-06', 22, 111, 'USD', 'partial', '{}', current_timestamp) - , (1, 'Re: REF001', '2023-03-06', 11, 10399, 'EUR', 'partial', '{}', current_timestamp) - , (1, 'Re: REF002', '2023-03-06', 11, 8500, 'EUR', 'complete', '{}', current_timestamp) - , (1, 'Re: REF003', '2023-03-06', 11, 9500, 'EUR', 'complete', '{}', current_timestamp) + $$ values (1, '“Protection”', '2023-05-02', 11, -1111, 'EUR', 'complete', '{tag1,tag2}', current_timestamp) + , (2, 'Payment of INV001', '2023-05-03', 22, -111, 'USD', 'complete', '{}', current_timestamp) + , (2, 'First payment of INV002', '2023-05-04', 22, -100, 'USD', 'partial', '{}', current_timestamp) + , (2, 'Second payment of INV002', '2023-05-05', 22, -122, 'USD', 'partial', '{}', current_timestamp) + , (2, 'Partial payment of INV003', '2023-05-06', 22, -111, 'USD', 'partial', '{}', current_timestamp) + , (1, 'Re: REF001', '2023-03-06', 11, -10399, 'EUR', 'partial', '{}', current_timestamp) + , (1, 'Re: REF002', '2023-03-06', 11, -8500, 'EUR', 'complete', '{}', current_timestamp) + , (1, 'Re: REF003', '2023-03-06', 11, -9500, 'EUR', 'complete', '{}', current_timestamp) + , (1, 'Re: RET001', '2023-03-07', 11, 111, 'EUR', 'complete', '{}', current_timestamp) + , (1, 'Re: RET002', '2023-03-08', 22, 111, 'EUR', 'partial', '{}', current_timestamp) $$, 'Should have created all payments' ); @@ -148,6 +162,8 @@ select bag_eq( , (16, 'Re: REF001') , (17, 'Re: REF002') , (18, 'Re: REF003') + , (19, 'Re: RET001') + , (20, 'Re: RET002') $$, 'Should have linked all expenses to payments' ); @@ -161,6 +177,8 @@ select bag_eq( , (16, 'partial') , (17, 'paid') , (18, 'paid') + , (19, 'paid') + , (20, 'partial') $$, 'Should have updated the status of expenses' ); diff --git a/test/attach_to_collection.sql b/test/attach_to_collection.sql index 042485b..205c09d 100644 --- a/test/attach_to_collection.sql +++ b/test/attach_to_collection.sql @@ -21,8 +21,8 @@ select function_privs_are('numerus', 'attach_to_collection', array ['uuid', 'tex set client_min_messages to warning; -truncate collection_attachment cascade; -truncate collection cascade; +truncate payment_attachment cascade; +truncate payment cascade; truncate payment_account cascade; truncate payment_method cascade; truncate company cascade; @@ -47,12 +47,12 @@ values (11, 1, 'cash', 'Cash 1') , (13, 1, 'other', 'Other') ; -insert into collection (collection_id, company_id, slug, description, collection_date, payment_account_id, amount, currency_code, payment_status) +insert into payment (payment_id, company_id, slug, description, payment_date, payment_account_id, amount, currency_code, payment_status) values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Collection 1', '2023-05-04', 12, 111, 'EUR', 'complete') , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'Collection 2', '2023-05-05', 13, 100, 'EUR', 'partial') ; -insert into collection_attachment (collection_id, original_filename, mime_type, content) +insert into payment_attachment (payment_id, original_filename, mime_type, content) values (17, 'something.txt', 'text/plain', convert_to('Once upon a time…', 'UTF-8')) ; @@ -67,7 +67,7 @@ select lives_ok( ); select bag_eq( - $$ select collection_id, original_filename, mime_type, convert_from(content, 'UTF-8') from collection_attachment $$, + $$ select payment_id, original_filename, mime_type, convert_from(content, 'UTF-8') from payment_attachment $$, $$ values (16, 'collection.txt', 'text/plain', 'To receive 42 €') , (17, 'collection.html', 'text/html', '

To receive 42 €

') $$, diff --git a/test/collection.sql b/test/collection.sql deleted file mode 100644 index 454ec55..0000000 --- a/test/collection.sql +++ /dev/null @@ -1,187 +0,0 @@ --- Test collection -set client_min_messages to warning; -create extension if not exists pgtap; -reset client_min_messages; - -begin; - -select plan(71); - -set search_path to numerus, auth, public; - -select has_table('collection'); -select has_pk('collection'); -select table_privs_are('collection', 'guest', array []::text[]); -select table_privs_are('collection', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); -select table_privs_are('collection', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); -select table_privs_are('collection', 'authenticator', array []::text[]); - -select has_column('collection', 'collection_id'); -select col_is_pk('collection', 'collection_id'); -select col_type_is('collection', 'collection_id', 'integer'); -select col_not_null('collection', 'collection_id'); -select col_hasnt_default('collection', 'collection_id'); - -select has_column('collection', 'company_id'); -select col_is_fk('collection', 'company_id'); -select fk_ok('collection', 'company_id', 'company', 'company_id'); -select col_type_is('collection', 'company_id', 'integer'); -select col_not_null('collection', 'company_id'); -select col_hasnt_default('collection', 'company_id'); - -select has_column('collection', 'slug'); -select col_is_unique('collection', 'slug'); -select col_type_is('collection', 'slug', 'uuid'); -select col_not_null('collection', 'slug'); -select col_has_default('collection', 'slug'); -select col_default_is('collection', 'slug', 'gen_random_uuid()'); - -select has_column('collection', 'description'); -select col_type_is('collection', 'description', 'text'); -select col_not_null('collection', 'description'); -select col_hasnt_default('collection', 'description'); - -select has_column('collection', 'collection_date'); -select col_type_is('collection', 'collection_date', 'date'); -select col_not_null('collection', 'collection_date'); -select col_has_default('collection', 'collection_date'); -select col_default_is('collection', 'collection_date', 'CURRENT_DATE'); - -select has_column('collection', 'payment_account_id'); -select col_is_fk('collection', 'payment_account_id'); -select fk_ok('collection', 'payment_account_id', 'payment_account', 'payment_account_id'); -select col_type_is('collection', 'payment_account_id', 'integer'); -select col_not_null('collection', 'payment_account_id'); -select col_hasnt_default('collection', 'payment_account_id'); - -select has_column('collection', 'amount'); -select col_type_is('collection', 'amount', 'integer'); -select col_not_null('collection', 'amount'); -select col_hasnt_default('collection', 'amount'); - -select has_column('collection', 'currency_code'); -select col_is_fk('collection', 'currency_code'); -select fk_ok('collection', 'currency_code', 'currency', 'currency_code'); -select col_type_is('collection', 'currency_code', 'text'); -select col_not_null('collection', 'currency_code'); -select col_hasnt_default('collection', 'currency_code'); - -select has_column('collection', 'tags'); -select col_type_is('collection', 'tags', 'tag_name[]'); -select col_not_null('collection', 'tags'); -select col_has_default('collection', 'tags'); -select col_default_is('collection', 'tags', '{}'); - -select has_column('collection', 'payment_status'); -select col_is_fk('collection', 'payment_status'); -select fk_ok('collection', 'payment_status', 'payment_status', 'payment_status'); -select col_type_is('collection', 'payment_status', 'text'); -select col_not_null('collection', 'payment_status'); -select col_has_default('collection', 'payment_status'); -select col_default_is('collection', 'payment_status', 'complete'); - -select has_column('collection', 'created_at'); -select col_type_is('collection', 'created_at', 'timestamp with time zone'); -select col_not_null('collection', 'created_at'); -select col_has_default('collection', 'created_at'); -select col_default_is('collection', 'created_at', 'CURRENT_TIMESTAMP'); - - -set client_min_messages to warning; -truncate collection cascade; -truncate payment_account 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 payment_account (payment_account_id, company_id, payment_account_type, name) -values (221, 2, 'other', 'Other 2') - , (441, 4, 'other', 'Other 4') -; - -insert into collection (company_id, description, payment_account_id, amount, currency_code) -values (2, 'Collection 20001', 221, 333, 'EUR') - , (4, 'Collection 40001', 441, 555, 'EUR') -; - - -prepare collection_data as -select company_id, description -from collection -order by company_id, description; - -set role invoicer; -select is_empty('collection_data', 'Should show no data when cookie is not set yet'); -reset role; - -select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog'); -select bag_eq( - 'collection_data', - $$ values (2, 'Collection 20001') - $$, - 'Should only list collections from the companies where demo@tandem.blog is user of' -); -reset role; - -select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog'); -select bag_eq( - 'collection_data', - $$ values (4, 'Collection 40001') - $$, - 'Should only list collections from the companies where admin@tandem.blog is user of' -); -reset role; - -select set_cookie('not-a-cookie'); -select throws_ok( - 'collection_data', - '42501', 'permission denied for table collection', - 'Should not allow select to guest users' -); -reset role; - -select throws_ok( - $$ insert into collection (company_id, description, payment_account_id, amount, currency_code) values (2, 'Nope', 221, 0, 'EUR') $$, - '23514', 'new row for relation "collection" violates check constraint "collection_amount_positive"', - 'Should not allow empty collections' -); - -select throws_ok( - $$ insert into collection (company_id, description, payment_account_id, amount, currency_code) values (2, 'Nope', 221, -1, 'EUR') $$, - '23514', 'new row for relation "collection" violates check constraint "collection_amount_positive"', - 'Should not allow negative collections' -); - - - -select * -from finish(); - -rollback; - diff --git a/test/collection_attachment.sql b/test/collection_attachment.sql deleted file mode 100644 index 32fc2d1..0000000 --- a/test/collection_attachment.sql +++ /dev/null @@ -1,131 +0,0 @@ --- Test collection_attachment -set client_min_messages to warning; -create extension if not exists pgtap; -reset client_min_messages; - -begin; - -select plan(29); - -set search_path to numerus, auth, public; - -select has_table('collection_attachment'); -select has_pk('collection_attachment'); -select table_privs_are('collection_attachment', 'guest', array []::text[]); -select table_privs_are('collection_attachment', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); -select table_privs_are('collection_attachment', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); -select table_privs_are('collection_attachment', 'authenticator', array []::text[]); - -select has_column('collection_attachment', 'collection_id'); -select col_is_pk('collection_attachment', 'collection_id'); -select col_is_fk('collection_attachment', 'collection_id'); -select fk_ok('collection_attachment', 'collection_id', 'collection', 'collection_id'); -select col_type_is('collection_attachment', 'collection_id', 'integer'); -select col_not_null('collection_attachment', 'collection_id'); -select col_hasnt_default('collection_attachment', 'collection_id'); - -select has_column('collection_attachment', 'original_filename'); -select col_type_is('collection_attachment', 'original_filename', 'text'); -select col_not_null('collection_attachment', 'original_filename'); -select col_hasnt_default('collection_attachment', 'original_filename'); - -select has_column('collection_attachment', 'mime_type'); -select col_type_is('collection_attachment', 'mime_type', 'text'); -select col_not_null('collection_attachment', 'mime_type'); -select col_hasnt_default('collection_attachment', 'mime_type'); - -select has_column('collection_attachment', 'content'); -select col_type_is('collection_attachment', 'content', 'bytea'); -select col_not_null('collection_attachment', 'content'); -select col_hasnt_default('collection_attachment', 'content'); - - -set client_min_messages to warning; -truncate collection_attachment cascade; -truncate collection cascade; -truncate company_user cascade; -truncate payment_method cascade; -truncate company 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 payment_account(payment_account_id, company_id, payment_account_type, name) -values (8, 2, 'other', 'Other 2') - , (9, 4, 'other', 'Other 4') -; - -insert into collection (collection_id, company_id, description, payment_account_id, collection_date, amount, currency_code) -values (13, 2, 'Payment 2', 8, '2011-01-11', 111, 'EUR') - , (14, 4, 'Payment 4', 9, '2022-02-22', 222, 'EUR') -; - -insert into collection_attachment (collection_id, original_filename, mime_type, content) -values (13, 'collection.txt', 'text/plain', convert_to('Collection 42', 'UTF8')) - , (14, 'collection.html', 'text/html', convert_to('Collection 42', 'UTF8')) -; - -prepare collection_attachment_data as -select collection_id, original_filename -from collection_attachment -order by collection_id, original_filename; - -set role invoicer; -select is_empty('collection_attachment_data', 'Should show no data when cookie is not set yet'); -reset role; - -select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog'); -select bag_eq( - 'collection_attachment_data', - $$ values (13, 'collection.txt') - $$, - 'Should only list collection attachmements of the companies where demo@tandem.blog is user of' -); -reset role; - -select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog'); -select bag_eq( - 'collection_attachment_data', - $$ values (14, 'collection.html') - $$, - 'Should only list collection attachmements of the companies where admin@tandem.blog is user of' -); -reset role; - -select set_cookie('not-a-cookie'); -select throws_ok( - 'collection_attachment_data', - '42501', 'permission denied for table collection_attachment', - 'Should not allow select to guest users' -); -reset role; - - -select * -from finish(); - -rollback; - diff --git a/test/edit_collection.sql b/test/edit_collection.sql index 811985f..e8d7d31 100644 --- a/test/edit_collection.sql +++ b/test/edit_collection.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(17); +select plan(19); set search_path to numerus, public; @@ -22,8 +22,8 @@ select function_privs_are('numerus', 'edit_collection', array ['uuid', 'date', ' set client_min_messages to warning; -truncate invoice_collection cascade; -truncate collection cascade; +truncate invoice_payment cascade; +truncate payment cascade; truncate invoice_product_tax cascade; truncate invoice_product cascade; truncate invoice cascade; @@ -75,6 +75,8 @@ values (13, 1, 'INV001', 9, '2011-01-11', 111, 'EUR', 'paid') , (16, 1, 'REF001', 9, '2023-03-03', 111, 'EUR', 'paid') , (17, 1, 'REF002', 9, '2023-03-03', 111, 'EUR', 'paid') , (18, 1, 'REF003', 9, '2023-03-03', 111, 'EUR', 'paid') + , (19, 1, 'RET001', 9, '2023-03-03', 111, 'EUR', 'paid') + , (20, 1, 'RET002', 9, '2023-03-03', 111, 'EUR', 'partial') ; insert into invoice_product (invoice_product_id, invoice_id, name, price) @@ -87,6 +89,8 @@ values (19, 13, 'P1', 111) , (25, 16, 'P1', 10000) , (26, 17, 'P1', 10000) , (27, 18, 'P1', 10000) + , (28, 19, 'P*', -111) + , (29, 20, 'P*', -333) ; insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate) @@ -102,7 +106,7 @@ values (11, 1, 'cash', 'Cash 1') , (13, 1, 'other', 'Other') ; -insert into collection (collection_id, company_id, slug, description, collection_date, payment_account_id, amount, currency_code, payment_status, tags) +insert into payment (payment_id, company_id, slug, description, payment_date, payment_account_id, amount, currency_code, payment_status, tags) values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-05-04', 12, 111, 'EUR', 'complete', '{tag1}') , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, 100, 'EUR', 'partial', '{tag2}') , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, 122, 'EUR', 'partial', '{tag1,tag3}') @@ -110,9 +114,11 @@ values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-0 , (20, 1, '65222c3b-4faa-4be4-b39c-5bd170a943cf', 'Re: REF001', '2023-03-07', 11, 10400, 'EUR', 'complete', '{}') , (21, 1, 'dbb699cf-d1f4-40ff-96cb-8f29e238d51d', 'Re: REF002', '2023-03-07', 11, 8500, 'EUR', 'complete', '{}') , (22, 1, '0756a50f-2957-4661-abd2-e422a848af4e', 'Re: REF003', '2023-03-07', 11, 9500, 'EUR', 'complete', '{}') + , (23, 1, '291ec84f-6b01-4cf2-aef6-3fde39000bb4', 'Re: RET001', '2023-03-08', 11, -111, 'EUR', 'complete', '{}') + , (24, 1, '346cf372-7d65-4a6c-b71b-dd03c611b3df', 'Re: RET003', '2023-03-09', 11, -111, 'EUR', 'partial', '{}') ; -insert into invoice_collection (invoice_id, collection_id) +insert into invoice_payment (invoice_id, payment_id) values (13, 16) , (14, 17) , (14, 18) @@ -120,6 +126,8 @@ values (13, 16) , (16, 20) , (17, 21) , (18, 22) + , (19, 23) + , (20, 24) ; select lives_ok( @@ -152,8 +160,19 @@ select lives_ok( 'Should be able to make partial a collection with multiple taxe.' ); +select lives_ok( + $$ select edit_collection('291ec84f-6b01-4cf2-aef6-3fde39000bb4', '2023-03-11', 11, 'Re: RET001', '-1.00', array[]::tag_name[]) $$, + 'Should be able to turn a negative invoice (e.g., a refund) back to partial.' +); + +select lives_ok( + $$ select edit_collection('346cf372-7d65-4a6c-b71b-dd03c611b3df', '2023-03-12', 12, 'Re: RET002', '-3.33', array[]::tag_name[]) $$, + 'Should be able to complete a negative invoice (e.g., a refund).' +); + + select bag_eq( - $$ select description, collection_date::text, payment_account_id, amount, payment_status, tags::text from collection $$, + $$ select description, payment_date::text, payment_account_id, amount, payment_status, tags::text from payment $$, $$ values ('Partial INV001', '2023-05-06', 13, 100, 'partial', '{tag1}') , ('First INV002', '2023-05-07', 12, 50, 'partial', '{tag1,tag3}') , ('Second INV002', '2023-05-06', 13, 122, 'partial', '{tag1,tag3}') @@ -161,6 +180,8 @@ select bag_eq( , ('Re: REF001', '2023-03-10', 11, 10399, 'partial', '{}') , ('Re: REF002', '2023-03-10', 11, 8499, 'partial', '{}') , ('Re: REF003', '2023-03-10', 11, 9499, 'partial', '{}') + , ('Re: RET001', '2023-03-11', 11, -100, 'partial', '{}') + , ('Re: RET002', '2023-03-12', 12, -333, 'complete', '{}') $$, 'Should have updated all collections' ); @@ -173,6 +194,8 @@ select bag_eq( , (16, 'partial') , (17, 'partial') , (18, 'partial') + , (19, 'partial') + , (20, 'paid') $$, 'Should have updated invoices too' ); diff --git a/test/edit_payment.sql b/test/edit_payment.sql index bd2029c..6b166e7 100644 --- a/test/edit_payment.sql +++ b/test/edit_payment.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(17); +select plan(19); set search_path to numerus, public; @@ -68,6 +68,8 @@ values (13, 1, 'INV001', 9, '2011-01-11', 111, 'EUR', 'paid') , (16, 1, 'REF001', 9, '2023-03-03', 10000, 'EUR', 'paid') , (17, 1, 'REF002', 9, '2023-03-03', 10000, 'EUR', 'paid') , (18, 1, 'REF003', 9, '2023-03-03', 10000, 'EUR', 'paid') + , (19, 1, 'RET001', 9, '2023-03-03', -111, 'EUR', 'paid') + , (20, 1, 'RET002', 9, '2023-03-03', -333, 'EUR', 'partial') ; insert into expense_tax (expense_id, tax_id, tax_rate) @@ -84,13 +86,15 @@ values (11, 1, 'cash', 'Cash 1') ; insert into payment (payment_id, company_id, slug, description, payment_date, payment_account_id, amount, currency_code, payment_status, tags) -values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-05-04', 12, 111, 'EUR', 'complete', '{tag1}') - , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, 100, 'EUR', 'partial', '{tag2}') - , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, 122, 'EUR', 'partial', '{tag1,tag3}') - , (19, 1, '5a524bee-8311-4d13-9adf-ef6310b26990', 'Partial INV003', '2023-05-07', 11, 123, 'EUR', 'partial', '{}') - , (20, 1, '65222c3b-4faa-4be4-b39c-5bd170a943cf', 'Re: REF001', '2023-03-07', 11, 10400, 'EUR', 'complete', '{}') - , (21, 1, 'dbb699cf-d1f4-40ff-96cb-8f29e238d51d', 'Re: REF002', '2023-03-07', 11, 8500, 'EUR', 'complete', '{}') - , (22, 1, '0756a50f-2957-4661-abd2-e422a848af4e', 'Re: REF003', '2023-03-07', 11, 9500, 'EUR', 'complete', '{}') +values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-05-04', 12, -111, 'EUR', 'complete', '{tag1}') + , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, -100, 'EUR', 'partial', '{tag2}') + , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, -122, 'EUR', 'partial', '{tag1,tag3}') + , (19, 1, '5a524bee-8311-4d13-9adf-ef6310b26990', 'Partial INV003', '2023-05-07', 11, -123, 'EUR', 'partial', '{}') + , (20, 1, '65222c3b-4faa-4be4-b39c-5bd170a943cf', 'Re: REF001', '2023-03-07', 11, -10400, 'EUR', 'complete', '{}') + , (21, 1, 'dbb699cf-d1f4-40ff-96cb-8f29e238d51d', 'Re: REF002', '2023-03-07', 11, -8500, 'EUR', 'complete', '{}') + , (22, 1, '0756a50f-2957-4661-abd2-e422a848af4e', 'Re: REF003', '2023-03-07', 11, -9500, 'EUR', 'complete', '{}') + , (23, 1, '291ec84f-6b01-4cf2-aef6-3fde39000bb4', 'Re: RET001', '2023-03-08', 11, -111, 'EUR', 'complete', '{}') + , (24, 1, '346cf372-7d65-4a6c-b71b-dd03c611b3df', 'Re: RET003', '2023-03-09', 11, -111, 'EUR', 'partial', '{}') ; insert into expense_payment (expense_id, payment_id) @@ -101,6 +105,8 @@ values (13, 16) , (16, 20) , (17, 21) , (18, 22) + , (19, 23) + , (20, 24) ; select lives_ok( @@ -133,15 +139,27 @@ select lives_ok( 'Should be able to make partial a payment with multiple taxe.' ); +select lives_ok( + $$ select edit_payment('291ec84f-6b01-4cf2-aef6-3fde39000bb4', '2023-03-11', 11, 'Re: RET001', '-1.00', array[]::tag_name[]) $$, + 'Should be able to turn a negative expense (e.g., a refund) back to partial.' +); + +select lives_ok( + $$ select edit_payment('346cf372-7d65-4a6c-b71b-dd03c611b3df', '2023-03-12', 12, 'Re: RET002', '-3.33', array[]::tag_name[]) $$, + 'Should be able to complete a negative expense (e.g., a refund).' +); + select bag_eq( $$ select description, payment_date::text, payment_account_id, amount, payment_status, tags::text from payment $$, - $$ values ('Partial INV001', '2023-05-06', 13, 100, 'partial', '{tag1}') - , ('First INV002', '2023-05-07', 12, 50, 'partial', '{tag1,tag3}') - , ('Second INV002', '2023-05-06', 13, 122, 'partial', '{tag1,tag3}') - , ('Complete INV003', '2023-05-01', 11, 333, 'complete', '{}') - , ('Re: REF001', '2023-03-10', 11, 10399, 'partial', '{}') - , ('Re: REF002', '2023-03-10', 11, 8499, 'partial', '{}') - , ('Re: REF003', '2023-03-10', 11, 9499, 'partial', '{}') + $$ values ('Partial INV001', '2023-05-06', 13, -100, 'partial', '{tag1}') + , ('First INV002', '2023-05-07', 12, -50, 'partial', '{tag1,tag3}') + , ('Second INV002', '2023-05-06', 13, -122, 'partial', '{tag1,tag3}') + , ('Complete INV003', '2023-05-01', 11, -333, 'complete', '{}') + , ('Re: REF001', '2023-03-10', 11, -10399, 'partial', '{}') + , ('Re: REF002', '2023-03-10', 11, -8499, 'partial', '{}') + , ('Re: REF003', '2023-03-10', 11, -9499, 'partial', '{}') + , ('Re: RET001', '2023-03-11', 11, 100, 'partial', '{}') + , ('Re: RET002', '2023-03-12', 12, 333, 'complete', '{}') $$, 'Should have updated all payments' ); @@ -154,6 +172,8 @@ select bag_eq( , (16, 'partial') , (17, 'partial') , (18, 'partial') + , (19, 'partial') + , (20, 'paid') $$, 'Should have updated expenses too' ); diff --git a/test/invoice_collection.sql b/test/invoice_payment.sql similarity index 63% rename from test/invoice_collection.sql rename to test/invoice_payment.sql index 0bd6378..1e2dacb 100644 --- a/test/invoice_collection.sql +++ b/test/invoice_payment.sql @@ -1,4 +1,4 @@ --- Test invoice_collection +-- Test invoice_payment set client_min_messages to warning; create extension if not exists pgtap; reset client_min_messages; @@ -9,32 +9,32 @@ select plan(23); set search_path to numerus, auth, public; -select has_table('invoice_collection'); -select has_pk('invoice_collection'); -select col_is_pk('invoice_collection', array['invoice_id', 'collection_id']); -select table_privs_are('invoice_collection', 'guest', array []::text[]); -select table_privs_are('invoice_collection', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); -select table_privs_are('invoice_collection', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); -select table_privs_are('invoice_collection', 'authenticator', array []::text[]); +select has_table('invoice_payment'); +select has_pk('invoice_payment'); +select col_is_pk('invoice_payment', array['invoice_id', 'payment_id']); +select table_privs_are('invoice_payment', 'guest', array []::text[]); +select table_privs_are('invoice_payment', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); +select table_privs_are('invoice_payment', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); +select table_privs_are('invoice_payment', 'authenticator', array []::text[]); -select has_column('invoice_collection', 'invoice_id'); -select col_is_fk('invoice_collection', 'invoice_id'); -select fk_ok('invoice_collection', 'invoice_id', 'invoice', 'invoice_id'); -select col_type_is('invoice_collection', 'invoice_id', 'integer'); -select col_not_null('invoice_collection', 'invoice_id'); -select col_hasnt_default('invoice_collection', 'invoice_id'); +select has_column('invoice_payment', 'invoice_id'); +select col_is_fk('invoice_payment', 'invoice_id'); +select fk_ok('invoice_payment', 'invoice_id', 'invoice', 'invoice_id'); +select col_type_is('invoice_payment', 'invoice_id', 'integer'); +select col_not_null('invoice_payment', 'invoice_id'); +select col_hasnt_default('invoice_payment', 'invoice_id'); -select has_column('invoice_collection', 'collection_id'); -select col_is_fk('invoice_collection', 'collection_id'); -select fk_ok('invoice_collection', 'collection_id', 'collection', 'collection_id'); -select col_type_is('invoice_collection', 'collection_id', 'integer'); -select col_not_null('invoice_collection', 'collection_id'); -select col_hasnt_default('invoice_collection', 'collection_id'); +select has_column('invoice_payment', 'payment_id'); +select col_is_fk('invoice_payment', 'payment_id'); +select fk_ok('invoice_payment', 'payment_id', 'payment', 'payment_id'); +select col_type_is('invoice_payment', 'payment_id', 'integer'); +select col_not_null('invoice_payment', 'payment_id'); +select col_hasnt_default('invoice_payment', 'payment_id'); set client_min_messages to warning; -truncate invoice_collection cascade; -truncate collection cascade; +truncate invoice_payment cascade; +truncate payment cascade; truncate payment_account cascade; truncate invoice cascade; truncate contact_tax_details cascade; @@ -89,28 +89,28 @@ values (17, 2, 'cash', 'Cash 2') , (18, 4, 'cash', 'Cash 4') ; -insert into collection (collection_id, company_id, description, collection_date, payment_account_id, amount, currency_code) +insert into payment (payment_id, company_id, description, payment_date, payment_account_id, amount, currency_code) values (21, 2, 'Collection INV001', '2022-01-11', 17, 111, 'EUR') , (22, 4, 'Collection INV002', '2022-02-23', 18, 222, 'EUR') ; -insert into invoice_collection (invoice_id, collection_id) +insert into invoice_payment (invoice_id, payment_id) values (13, 21) , (14, 22) ; -prepare invoice_collection_data as -select invoice_id, collection_id -from invoice_collection -order by invoice_id, collection_id; +prepare invoice_payment_data as +select invoice_id, payment_id +from invoice_payment +order by invoice_id, payment_id; set role invoicer; -select is_empty('invoice_collection_data', 'Should show no data when cookie is not set yet'); +select is_empty('invoice_payment_data', 'Should show no data when cookie is not set yet'); reset role; select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog'); select bag_eq( - 'invoice_collection_data', + 'invoice_payment_data', $$ values (13, 21) $$, 'Should only list tax of products of the companies where demo@tandem.blog is user of' @@ -119,7 +119,7 @@ reset role; select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog'); select bag_eq( - 'invoice_collection_data', + 'invoice_payment_data', $$ values (14, 22) $$, 'Should only list tax of products of the companies where admin@tandem.blog is user of' @@ -128,8 +128,8 @@ reset role; select set_cookie('not-a-cookie'); select throws_ok( - 'invoice_collection_data', - '42501', 'permission denied for table invoice_collection', + 'invoice_payment_data', + '42501', 'permission denied for table invoice_payment', 'Should not allow select to guest users' ); reset role; diff --git a/test/payment.sql b/test/payment.sql index dac7be5..b503c98 100644 --- a/test/payment.sql +++ b/test/payment.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(71); +select plan(70); set search_path to numerus, auth, public; @@ -168,16 +168,10 @@ reset role; select throws_ok( $$ insert into payment (company_id, description, payment_account_id, amount, currency_code) values (2, 'Nope', 221, 0, 'EUR') $$, - '23514', 'new row for relation "payment" violates check constraint "payment_amount_positive"', + '23514', 'new row for relation "payment" violates check constraint "payment_amount_not_zero"', 'Should not allow empty payments' ); -select throws_ok( - $$ insert into payment (company_id, description, payment_account_id, amount, currency_code) values (2, 'Nope', 221, -1, 'EUR') $$, - '23514', 'new row for relation "payment" violates check constraint "payment_amount_positive"', - 'Should not allow negative payments' -); - select * from finish(); diff --git a/test/remove_collection.sql b/test/remove_collection.sql index 4c49d59..bdbccb5 100644 --- a/test/remove_collection.sql +++ b/test/remove_collection.sql @@ -22,9 +22,9 @@ select function_privs_are('numerus', 'remove_collection', array ['uuid'], 'authe set client_min_messages to warning; -truncate invoice_collection; -truncate collection_attachment; -truncate collection cascade; +truncate invoice_payment; +truncate payment_attachment; +truncate payment cascade; truncate invoice_product cascade; truncate invoice cascade; truncate contact_tax_details cascade; @@ -76,21 +76,21 @@ values (11, 1, 'cash', 'Cash 1') , (13, 1, 'other', 'Other') ; -insert into collection (collection_id, company_id, slug, description, collection_date, payment_account_id, amount, currency_code, payment_status, tags) +insert into payment (payment_id, company_id, slug, description, payment_date, payment_account_id, amount, currency_code, payment_status, tags) values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Collection INV001', '2023-05-04', 12, 111, 'EUR', 'complete', '{tag1}') , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, 100, 'EUR', 'partial', '{tag2}') , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, 122, 'EUR', 'partial', '{tag1,tag3}') , (19, 1, '5a524bee-8311-4d13-9adf-ef6310b26990', 'Partial INV003', '2023-05-07', 11, 123, 'EUR', 'partial', '{}') ; -insert into invoice_collection (invoice_id, collection_id) +insert into invoice_payment (invoice_id, payment_id) values (13, 16) , (14, 17) , (14, 18) , (15, 19) ; -insert into collection_attachment (collection_id, original_fileName, mime_type, content) +insert into payment_attachment (payment_id, original_fileName, mime_type, content) values (16, 'collection.txt', 'text/plain', convert_to('Pay 42', 'UTF-8')) , (18, 'empty.html', 'text/html', convert_to('empty', 'UTF-8')) , (19, 'collection.html', 'text/html', convert_to(' PAY 42', 'UTF-8')) @@ -112,21 +112,21 @@ select lives_ok( ); select bag_eq( - $$ select description, collection_date::text, payment_account_id, amount, payment_status, tags::text from collection $$, + $$ select description, payment_date::text, payment_account_id, amount, payment_status, tags::text from payment $$, $$ values ('Second INV002', '2023-05-06', 13, 122, 'partial', '{tag1,tag3}') $$, 'Should have deleted all given collections' ); select bag_eq( - $$ select invoice_id, collection_id from invoice_collection$$, + $$ select invoice_id, payment_id from invoice_payment$$, $$ values (14, 18) $$, 'Should have deleted all related invoices’ collections' ); select bag_eq( - $$ select collection_id, original_filename from collection_attachment $$, + $$ select payment_id, original_filename from payment_attachment $$, $$ values (18, 'empty.html') $$, 'Should have deleted all related attachments' ); diff --git a/test/remove_payment.sql b/test/remove_payment.sql index f0982e8..76b37b2 100644 --- a/test/remove_payment.sql +++ b/test/remove_payment.sql @@ -62,10 +62,10 @@ values (11, 1, 'cash', 'Cash 1') ; insert into payment (payment_id, company_id, slug, description, payment_date, payment_account_id, amount, currency_code, payment_status, tags) -values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-05-04', 12, 111, 'EUR', 'complete', '{tag1}') - , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, 100, 'EUR', 'partial', '{tag2}') - , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, 122, 'EUR', 'partial', '{tag1,tag3}') - , (19, 1, '5a524bee-8311-4d13-9adf-ef6310b26990', 'Partial INV003', '2023-05-07', 11, 123, 'EUR', 'partial', '{}') +values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-05-04', 12, -111, 'EUR', 'complete', '{tag1}') + , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, -100, 'EUR', 'partial', '{tag2}') + , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, -122, 'EUR', 'partial', '{tag1,tag3}') + , (19, 1, '5a524bee-8311-4d13-9adf-ef6310b26990', 'Partial INV003', '2023-05-07', 11, -123, 'EUR', 'partial', '{}') ; insert into expense_payment (expense_id, payment_id) @@ -98,7 +98,7 @@ select lives_ok( select bag_eq( $$ select description, payment_date::text, payment_account_id, amount, payment_status, tags::text from payment $$, - $$ values ('Second INV002', '2023-05-06', 13, 122, 'partial', '{tag1,tag3}') + $$ values ('Second INV002', '2023-05-06', 13, -122, 'partial', '{tag1,tag3}') $$, 'Should have deleted all given payments' ); diff --git a/verify/_merge_collection_into_payment.sql b/verify/_merge_collection_into_payment.sql new file mode 100644 index 0000000..6db385f --- /dev/null +++ b/verify/_merge_collection_into_payment.sql @@ -0,0 +1,7 @@ +-- Verify numerus:_merge_collection_into_payment on pg + +BEGIN; + +-- XXX Add verifications here. + +ROLLBACK; diff --git a/verify/add_collection@v3.sql b/verify/add_collection@v3.sql new file mode 100644 index 0000000..373b38f --- /dev/null +++ b/verify/add_collection@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:add_collection on pg + +begin; + +select has_function_privilege('numerus.add_collection(integer, integer, date, integer, text, text, numerus.tag_name[])', 'execute'); + +rollback; diff --git a/verify/add_payment@v3.sql b/verify/add_payment@v3.sql new file mode 100644 index 0000000..4758fca --- /dev/null +++ b/verify/add_payment@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:add_payment on pg + +begin; + +select has_function_privilege('numerus.add_payment(integer, integer, date, integer, text, text, numerus.tag_name[])', 'execute'); + +rollback; diff --git a/verify/attach_to_collection@v3.sql b/verify/attach_to_collection@v3.sql new file mode 100644 index 0000000..9a491e4 --- /dev/null +++ b/verify/attach_to_collection@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:attach_to_collection on pg + +begin; + +select has_function_privilege('numerus.attach_to_collection(uuid, text, text, bytea)', 'execute'); + +rollback; diff --git a/verify/edit_collection@v3.sql b/verify/edit_collection@v3.sql new file mode 100644 index 0000000..19976aa --- /dev/null +++ b/verify/edit_collection@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:edit_collection on pg + +begin; + +select has_function_privilege('numerus.edit_collection(uuid, date, integer, text, text, numerus.tag_name[])', 'execute'); + +rollback; diff --git a/verify/edit_payment@v3.sql b/verify/edit_payment@v3.sql new file mode 100644 index 0000000..1a5d49f --- /dev/null +++ b/verify/edit_payment@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:edit_payment on pg + +begin; + +select has_function_privilege('numerus.edit_payment(uuid, date, integer, text, text, numerus.tag_name[])', 'execute'); + +rollback; diff --git a/verify/invoice_payment.sql b/verify/invoice_payment.sql new file mode 100644 index 0000000..de1f000 --- /dev/null +++ b/verify/invoice_payment.sql @@ -0,0 +1,13 @@ +-- Verify numerus:invoice_payment on pg + +begin; + +select invoice_id + , payment_id +from numerus.invoice_payment +where false; + +select 1 / count(*) from pg_class where oid = 'numerus.invoice_payment'::regclass and relrowsecurity; +select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.invoice_payment'::regclass; + +rollback; diff --git a/verify/remove_collection@v3.sql b/verify/remove_collection@v3.sql new file mode 100644 index 0000000..e468d57 --- /dev/null +++ b/verify/remove_collection@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:remove_collection on pg + +begin; + +select has_function_privilege('numerus.remove_collection(uuid)', 'execute'); + +rollback; diff --git a/verify/update_expense_payment_status@v3.sql b/verify/update_expense_payment_status@v3.sql new file mode 100644 index 0000000..9dd16e4 --- /dev/null +++ b/verify/update_expense_payment_status@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:update_expense_payment_status on pg + +begin; + +select has_function_privilege('numerus.update_expense_payment_status(integer, integer, integer)', 'execute'); + +rollback; diff --git a/verify/update_invoice_collection_status@v3.sql b/verify/update_invoice_collection_status@v3.sql new file mode 100644 index 0000000..91d57d7 --- /dev/null +++ b/verify/update_invoice_collection_status@v3.sql @@ -0,0 +1,7 @@ +-- Verify numerus:update_invoice_collection_status on pg + +begin; + +select has_function_privilege('numerus.update_invoice_collection_status(integer, integer, integer)', 'execute'); + +rollback; diff --git a/web/template/payments/index.gohtml b/web/template/payments/index.gohtml index 8e8a99c..08f8008 100644 --- a/web/template/payments/index.gohtml +++ b/web/template/payments/index.gohtml @@ -84,7 +84,7 @@ {{ . }} {{- end }} - {{- if eq .Type "P" -}}-{{ end }}{{ .Total | formatPrice }} + {{ .Total | formatPrice }} {{ if .OriginalFileName }}