Show the invoice subtotal, taxes, and total when creating it
This commit is contained in:
parent
980db529f1
commit
985f843e8e
|
@ -0,0 +1,64 @@
|
||||||
|
-- Deploy numerus:compute_new_invoice_amount to pg
|
||||||
|
-- requires: schema_numerus
|
||||||
|
-- requires: company
|
||||||
|
-- requires: currency
|
||||||
|
-- requires: tax
|
||||||
|
-- requires: new_invoice_product
|
||||||
|
-- requires: new_invoice_amount
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
create or replace function compute_new_invoice_amount(company_id integer, products new_invoice_product[]) returns new_invoice_amount as
|
||||||
|
$$
|
||||||
|
declare
|
||||||
|
result new_invoice_amount;
|
||||||
|
begin
|
||||||
|
if array_length(products, 1) is null then
|
||||||
|
select to_price(0, decimal_digits), array[]::text[][], to_price(0, decimal_digits)
|
||||||
|
from company
|
||||||
|
join currency using (currency_code)
|
||||||
|
where company.company_id = compute_new_invoice_amount.company_id
|
||||||
|
into result.subtotal, result.taxes, result.total;
|
||||||
|
else
|
||||||
|
with product as (
|
||||||
|
select round(parse_price(price, currency.decimal_digits) * quantity * (1 - discount_rate))::integer as subtotal
|
||||||
|
, tax
|
||||||
|
, decimal_digits
|
||||||
|
from unnest(products)
|
||||||
|
join company on company.company_id = compute_new_invoice_amount.company_id
|
||||||
|
join currency using (currency_code)
|
||||||
|
)
|
||||||
|
, tax_amount as (
|
||||||
|
select tax_id
|
||||||
|
, sum(round(subtotal * tax.rate)::integer)::integer as amount
|
||||||
|
, decimal_digits
|
||||||
|
from product, unnest(product.tax) as product_tax(tax_id)
|
||||||
|
join tax using (tax_id)
|
||||||
|
group by tax_id, decimal_digits
|
||||||
|
)
|
||||||
|
, tax_total as (
|
||||||
|
select sum(amount)::integer as amount, array_agg(array[name, to_price(amount, decimal_digits)]) as taxes
|
||||||
|
from tax_amount
|
||||||
|
join tax using (tax_id)
|
||||||
|
)
|
||||||
|
select to_price(sum(subtotal)::integer, decimal_digits)
|
||||||
|
, coalesce(taxes, array[]::text[][])
|
||||||
|
, to_price(sum(subtotal)::integer + coalesce(tax_total.amount, 0), decimal_digits) as total
|
||||||
|
from product, tax_total
|
||||||
|
group by tax_total.amount, taxes, decimal_digits
|
||||||
|
into result.subtotal, result.taxes, result.total;
|
||||||
|
end if;
|
||||||
|
|
||||||
|
return result;
|
||||||
|
end
|
||||||
|
$$
|
||||||
|
language plpgsql
|
||||||
|
stable;
|
||||||
|
|
||||||
|
revoke execute on function compute_new_invoice_amount(integer, new_invoice_product[]) from public;
|
||||||
|
grant execute on function compute_new_invoice_amount(integer, new_invoice_product[]) to invoicer;
|
||||||
|
grant execute on function compute_new_invoice_amount(integer, new_invoice_product[]) to admin;
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,14 @@
|
||||||
|
-- Deploy numerus:new_invoice_amount to pg
|
||||||
|
-- requires: schema_numerus
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
create type new_invoice_amount as (
|
||||||
|
subtotal text,
|
||||||
|
taxes text[][],
|
||||||
|
total text
|
||||||
|
);
|
||||||
|
|
||||||
|
commit;
|
|
@ -66,10 +66,31 @@ func GetInvoiceForm(w http.ResponseWriter, r *http.Request, params httprouter.Pa
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
type newInvoicePage struct {
|
||||||
|
Form *invoiceForm
|
||||||
|
Subtotal string
|
||||||
|
Taxes [][]string
|
||||||
|
Total string
|
||||||
|
}
|
||||||
|
|
||||||
|
func newNewInvoicePage(form *invoiceForm, r *http.Request) *newInvoicePage {
|
||||||
|
page := &newInvoicePage{
|
||||||
|
Form: form,
|
||||||
|
}
|
||||||
|
conn := getConn(r)
|
||||||
|
company := mustGetCompany(r)
|
||||||
|
err := conn.QueryRow(r.Context(), "select subtotal, taxes, total from compute_new_invoice_amount($1, $2)", company.Id, NewInvoiceProductArray(form.Products)).Scan(&page.Subtotal, &page.Taxes, &page.Total)
|
||||||
|
if err != nil {
|
||||||
|
panic(err)
|
||||||
|
}
|
||||||
|
return page
|
||||||
|
}
|
||||||
|
|
||||||
func mustRenderNewInvoiceForm(w http.ResponseWriter, r *http.Request, form *invoiceForm) {
|
func mustRenderNewInvoiceForm(w http.ResponseWriter, r *http.Request, form *invoiceForm) {
|
||||||
locale := getLocale(r)
|
locale := getLocale(r)
|
||||||
form.Customer.EmptyLabel = gettext("Select a customer to bill.", locale)
|
form.Customer.EmptyLabel = gettext("Select a customer to bill.", locale)
|
||||||
mustRenderAppTemplate(w, r, "invoices/new.gohtml", form)
|
page := newNewInvoicePage(form, r)
|
||||||
|
mustRenderAppTemplate(w, r, "invoices/new.gohtml", page)
|
||||||
}
|
}
|
||||||
|
|
||||||
func mustRenderNewInvoiceProductsForm(w http.ResponseWriter, r *http.Request, form *invoiceForm) {
|
func mustRenderNewInvoiceProductsForm(w http.ResponseWriter, r *http.Request, form *invoiceForm) {
|
||||||
|
@ -158,7 +179,7 @@ func HandleAddProductsToInvoice(w http.ResponseWriter, r *http.Request, _ httpro
|
||||||
|
|
||||||
index := len(form.Products)
|
index := len(form.Products)
|
||||||
productsId := r.Form["id"]
|
productsId := r.Form["id"]
|
||||||
rows := conn.MustQuery(r.Context(), "select product_id, name, description, to_price(price, decimal_digits), 1 as quantity, 0 as discount, array_agg(tax_id) from product join company using (company_id) join currency using (currency_code) left join product_tax using (product_id) where product_id = any ($1) group by product_id, name, description, price, decimal_digits", productsId)
|
rows := conn.MustQuery(r.Context(), "select product_id, name, description, to_price(price, decimal_digits), 1 as quantity, 0 as discount, array_remove(array_agg(tax_id), null) from product join company using (company_id) join currency using (currency_code) left join product_tax using (product_id) where product_id = any ($1) group by product_id, name, description, price, decimal_digits", productsId)
|
||||||
defer rows.Close()
|
defer rows.Close()
|
||||||
for rows.Next() {
|
for rows.Next() {
|
||||||
product := newInvoiceProductForm(index, company, locale, form.Tax.Options)
|
product := newInvoiceProductForm(index, company, locale, form.Tax.Options)
|
||||||
|
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:compute_new_invoice_amount from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.compute_new_invoice_amount(integer, numerus.new_invoice_product[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:new_invoice_amount from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop type if exists numerus.new_invoice_amount;
|
||||||
|
|
||||||
|
commit;
|
|
@ -58,3 +58,5 @@ next_invoice_number [schema_numerus invoice_number_counter] 2023-02-17T13:21:48Z
|
||||||
add_invoice [schema_numerus invoice company currency parse_price new_invoice_product tax invoice_product invoice_product_tax next_invoice_number] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices
|
add_invoice [schema_numerus invoice company currency parse_price new_invoice_product tax invoice_product invoice_product_tax next_invoice_number] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices
|
||||||
invoice_tax_amount [schema_numerus invoice_product invoice_product_tax] 2023-02-22T12:08:35Z jordi fita mas <jordi@tandem.blog> # Add view for invoice tax amount
|
invoice_tax_amount [schema_numerus invoice_product invoice_product_tax] 2023-02-22T12:08:35Z jordi fita mas <jordi@tandem.blog> # Add view for invoice tax amount
|
||||||
invoice_amount [schema_numerus invoice_product invoice_tax_amount] 2023-02-22T12:58:46Z jordi fita mas <jordi@tandem.blog> # Add view to compute subtotal and total for invoices
|
invoice_amount [schema_numerus invoice_product invoice_tax_amount] 2023-02-22T12:58:46Z jordi fita mas <jordi@tandem.blog> # Add view to compute subtotal and total for invoices
|
||||||
|
new_invoice_amount [schema_numerus] 2023-02-23T12:08:25Z jordi fita mas <jordi@tandem.blog> # Add type to return when computing new invoice amounts
|
||||||
|
compute_new_invoice_amount [schema_numerus company currency tax new_invoice_product new_invoice_amount] 2023-02-23T12:20:13Z jordi fita mas <jordi@tandem.blog> # Add function to compute the subtotal, taxes, and total amounts for a new invoice
|
||||||
|
|
|
@ -0,0 +1,66 @@
|
||||||
|
-- Test compute_new_invoice_amount
|
||||||
|
set client_min_messages to warning;
|
||||||
|
create extension if not exists pgtap;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select plan(14);
|
||||||
|
|
||||||
|
set search_path to numerus, auth, public;
|
||||||
|
|
||||||
|
select has_function('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]']);
|
||||||
|
select function_lang_is('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'plpgsql');
|
||||||
|
select function_returns('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'new_invoice_amount');
|
||||||
|
select isnt_definer('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]']);
|
||||||
|
select volatility_is('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'stable');
|
||||||
|
select function_privs_are('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'guest', array []::text[]);
|
||||||
|
select function_privs_are('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'invoicer', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'admin', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'compute_new_invoice_amount', array ['integer', 'new_invoice_product[]'], 'authenticator', array []::text[]);
|
||||||
|
|
||||||
|
set client_min_messages to warning;
|
||||||
|
truncate tax cascade;
|
||||||
|
truncate company cascade;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code)
|
||||||
|
values (1, 'Company 1', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR')
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into tax (tax_id, company_id, name, rate)
|
||||||
|
values (2, 1, 'IRPF -15 %', -0.15)
|
||||||
|
, (3, 1, 'IVA 4 %', 0.04)
|
||||||
|
, (4, 1, 'IVA 10 %', 0.10)
|
||||||
|
, (5, 1, 'IVA 21 %', 0.21)
|
||||||
|
;
|
||||||
|
|
||||||
|
select is(
|
||||||
|
compute_new_invoice_amount(1, '{}'),
|
||||||
|
'(0.00,"{}",0.00)'::new_invoice_amount
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
compute_new_invoice_amount(1, '{"(6,P,D,1.00,1,0.0,\"{2,5}\")","(6,P,D,2.00,2,0.1,{3})"}'),
|
||||||
|
'(4.60,"{{IRPF -15 %,-0.15},{IVA 4 %,0.14},{IVA 21 %,0.21}}",4.80)'::new_invoice_amount
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
compute_new_invoice_amount(1, '{"(6,P,D,2.22,3,0.0,\"{2,4,5}\")","(6,P,D,3.33,4,0.2,{4})"}'),
|
||||||
|
'(17.32,"{{IRPF -15 %,-1.00},{IVA 10 %,1.74},{IVA 21 %,1.40}}",19.46)'::new_invoice_amount
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
compute_new_invoice_amount(1, '{"(6,P,D,4.44,5,0.0,\"{4,5}\")","(6,P,D,5.55,6,0.1,\"{5,3}\")"}'),
|
||||||
|
'(52.17,"{{IVA 4 %,1.20},{IVA 10 %,2.22},{IVA 21 %,10.95}}",66.54)'::new_invoice_amount
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
compute_new_invoice_amount(1, '{"(6,P,D,7.77,8,0.0,\"{}\")"}'),
|
||||||
|
'(62.16,"{}",62.16)'::new_invoice_amount
|
||||||
|
);
|
||||||
|
|
||||||
|
select *
|
||||||
|
from finish();
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,22 @@
|
||||||
|
-- Test new_invoice_amount
|
||||||
|
set client_min_messages to warning;
|
||||||
|
create extension if not exists pgtap;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select plan(5);
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
select has_composite('numerus', 'new_invoice_amount', 'Composite type numerus.new_invoice_amount should exist');
|
||||||
|
select columns_are('numerus', 'new_invoice_amount', array['subtotal', 'taxes', 'total']);
|
||||||
|
select col_type_is('numerus'::name, 'new_invoice_amount'::name, 'subtotal'::name, 'text');
|
||||||
|
select col_type_is('numerus'::name, 'new_invoice_amount'::name, 'taxes'::name, 'text[]');
|
||||||
|
select col_type_is('numerus'::name, 'new_invoice_amount'::name, 'total'::name, 'text');
|
||||||
|
|
||||||
|
|
||||||
|
select *
|
||||||
|
from finish();
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:compute_new_invoice_amount on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select has_function_privilege('numerus.compute_new_invoice_amount(integer, numerus.new_invoice_product[])', 'execute');
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:new_invoice_amount on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select pg_catalog.has_type_privilege('numerus.new_invoice_amount', 'usage');
|
||||||
|
|
||||||
|
rollback;
|
|
@ -16,6 +16,7 @@
|
||||||
<form method="POST" action="{{ companyURI "/invoices" }}">
|
<form method="POST" action="{{ companyURI "/invoices" }}">
|
||||||
{{ csrfToken }}
|
{{ csrfToken }}
|
||||||
|
|
||||||
|
{{ with .Form -}}
|
||||||
{{ template "select-field" .Customer }}
|
{{ template "select-field" .Customer }}
|
||||||
{{ template "input-field" .Number }}
|
{{ template "input-field" .Number }}
|
||||||
{{ template "input-field" .Date }}
|
{{ template "input-field" .Date }}
|
||||||
|
@ -32,6 +33,26 @@
|
||||||
{{ template "select-field" .Tax }}
|
{{ template "select-field" .Tax }}
|
||||||
</fieldset>
|
</fieldset>
|
||||||
{{- end }}
|
{{- end }}
|
||||||
|
{{- end }}
|
||||||
|
|
||||||
|
<table>
|
||||||
|
<tbody>
|
||||||
|
<tr>
|
||||||
|
<th scope="row">{{(pgettext "Subtotal" "title")}}</th>
|
||||||
|
<td class="numeric">{{ .Subtotal | formatPrice }}</td>
|
||||||
|
</tr>
|
||||||
|
{{- range $tax := .Taxes }}
|
||||||
|
<tr>
|
||||||
|
<th scope="row">{{ index . 0 }}</th>
|
||||||
|
<td class="numeric">{{ index . 1 | formatPrice }}</td>
|
||||||
|
</tr>
|
||||||
|
{{- end }}
|
||||||
|
<tr>
|
||||||
|
<th scope="row">{{(pgettext "Total" "title")}}</th>
|
||||||
|
<td class="numeric">{{ .Total | formatPrice }}</td>
|
||||||
|
</tr>
|
||||||
|
</tbody>
|
||||||
|
</table>
|
||||||
|
|
||||||
<fieldset>
|
<fieldset>
|
||||||
<button formnovalidate name="action" value="products"
|
<button formnovalidate name="action" value="products"
|
||||||
|
|
Loading…
Reference in New Issue