2023-02-16 22:09:10 +00:00
|
|
|
-- Deploy numerus:add_invoice to pg
|
|
|
|
-- requires: schema_numerus
|
|
|
|
-- requires: invoice
|
|
|
|
-- requires: company
|
|
|
|
-- requires: currency
|
|
|
|
-- requires: parse_price
|
|
|
|
-- requires: new_invoice_product
|
|
|
|
-- requires: tax
|
|
|
|
-- requires: invoice_product
|
Move the product_id field from invoice_product to a separate table
We are going to allow invoices with products that are not (yet) inserted
into the products table.
We always allowed to have products in invoices with a totally different
name, description, price, and whatnot, but until now we had the product
id in these invoice lines for statistics purposes.
However, Oriol raised the concern that this requires for the products
to be inserted before we can create an invoice with them, and we do not
plan to have a “create product while invoicing” feature, thus it would
mean that people would need to cancel the new invoice, create the new
product, and then start the invoice again from scratch.
The compromise is to allow products in the invoice that do not have a
product_id, meaning that at the time the invoice was created they were
not (yet) in the products table. Oriol sees this stop-invoice-create-
product issue more important than the accurate statistics of product
sales, as it will probably be only one or two units off, anyway.
I did not want to allow NULL values to the invoice product’s product_id
field, because NULL means “dunno” instead of “no product”, so i had to
split that field to a separate table that relates an invoice product
with a registered product.
2023-04-19 17:30:12 +00:00
|
|
|
-- requires: invoice_product_product
|
2023-02-16 22:09:10 +00:00
|
|
|
-- requires: invoice_product_tax
|
2023-02-18 13:49:02 +00:00
|
|
|
-- requires: next_invoice_number
|
2023-03-10 13:02:55 +00:00
|
|
|
-- requires: tag_name
|
2023-02-16 22:09:10 +00:00
|
|
|
|
|
|
|
begin;
|
|
|
|
|
|
|
|
set search_path to numerus, public;
|
|
|
|
|
Remove the number field from new invoice form
Initially, this field was meant to be left almost always blank, except
for when we deleted invoiced and had to “replace” its number with a new
invoice; using the automatic numbering in this cas would not “fill in”
the missing number in the sequence.
However, we decide to not allow removing invoicer not edit their
numbers, therefore, if everything goes as planned, there should not be
any gap in the sequence, and that field is rendered useless.
Oriol suggested making it a read-only field, both for new and edit
forms, but i do not think it makes sense to have a field if you can not
edit it at all, specially in the new invoice dialog, where it would
always be blank. In the edit form we already show the number in the
title and breadcrumbs, thus no need for the read-only field as
reference.
I still keep a Number member to the form struct, but is now a string
(kind of “a read-only field”, in a way) and just to be written in the
title or breadcrumbs. I did not like the idea of adding a new SQL
query just for that value.
2023-04-01 13:57:56 +00:00
|
|
|
create or replace function add_invoice(company integer, invoice_date date, contact_id integer, notes text, payment_method_id integer, tags tag_name[], products new_invoice_product[]) returns uuid as
|
2023-02-16 22:09:10 +00:00
|
|
|
$$
|
|
|
|
declare
|
|
|
|
iid integer;
|
|
|
|
pslug uuid;
|
|
|
|
product new_invoice_product;
|
|
|
|
ccode text;
|
|
|
|
ipid integer;
|
|
|
|
begin
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
insert into invoice (company_id, invoice_number, invoice_date, contact_id, notes, tags, currency_code, payment_method_id)
|
2023-03-10 13:02:55 +00:00
|
|
|
select company_id
|
Remove the number field from new invoice form
Initially, this field was meant to be left almost always blank, except
for when we deleted invoiced and had to “replace” its number with a new
invoice; using the automatic numbering in this cas would not “fill in”
the missing number in the sequence.
However, we decide to not allow removing invoicer not edit their
numbers, therefore, if everything goes as planned, there should not be
any gap in the sequence, and that field is rendered useless.
Oriol suggested making it a read-only field, both for new and edit
forms, but i do not think it makes sense to have a field if you can not
edit it at all, specially in the new invoice dialog, where it would
always be blank. In the edit form we already show the number in the
title and breadcrumbs, thus no need for the read-only field as
reference.
I still keep a Number member to the form struct, but is now a string
(kind of “a read-only field”, in a way) and just to be written in the
title or breadcrumbs. I did not like the idea of adding a new SQL
query just for that value.
2023-04-01 13:57:56 +00:00
|
|
|
, next_invoice_number(add_invoice.company, invoice_date)
|
2023-02-16 22:09:10 +00:00
|
|
|
, invoice_date
|
|
|
|
, contact_id
|
|
|
|
, notes
|
Replace tag relations with array attributes
It all started when i wanted to try to filter invoices by multiple tags
using an “AND”, instead of “OR” as it was doing until now. But
something felt off and seemed to me that i was doing thing much more
complex than needed, all to be able to list the tags as a suggestion
in the input field—which i am not doing yet.
I found this article series[0] exploring different approaches for
tagging, which includes the one i was using, and comparing their
performance. I have not actually tested it, but it seems that i have
chosen the worst option, in both query time and storage.
I attempted to try using an array attribute to each table, which is more
or less the same they did in the articles but without using a separate
relation for tags, and i found out that all the queries were way easier
to write, and needed two joins less, so it was a no-brainer.
[0]: http://www.databasesoup.com/2015/01/tag-all-things.html
2023-04-07 19:31:35 +00:00
|
|
|
, tags
|
2023-02-16 22:09:10 +00:00
|
|
|
, currency_code
|
2023-03-05 17:50:57 +00:00
|
|
|
, add_invoice.payment_method_id
|
2023-02-16 22:09:10 +00:00
|
|
|
from company
|
2023-03-10 13:02:55 +00:00
|
|
|
where company.company_id = add_invoice.company
|
2023-02-16 22:09:10 +00:00
|
|
|
returning invoice_id, slug, currency_code
|
|
|
|
into iid, pslug, ccode;
|
|
|
|
|
|
|
|
foreach product in array products
|
|
|
|
loop
|
Move the product_id field from invoice_product to a separate table
We are going to allow invoices with products that are not (yet) inserted
into the products table.
We always allowed to have products in invoices with a totally different
name, description, price, and whatnot, but until now we had the product
id in these invoice lines for statistics purposes.
However, Oriol raised the concern that this requires for the products
to be inserted before we can create an invoice with them, and we do not
plan to have a “create product while invoicing” feature, thus it would
mean that people would need to cancel the new invoice, create the new
product, and then start the invoice again from scratch.
The compromise is to allow products in the invoice that do not have a
product_id, meaning that at the time the invoice was created they were
not (yet) in the products table. Oriol sees this stop-invoice-create-
product issue more important than the accurate statistics of product
sales, as it will probably be only one or two units off, anyway.
I did not want to allow NULL values to the invoice product’s product_id
field, because NULL means “dunno” instead of “no product”, so i had to
split that field to a separate table that relates an invoice product
with a registered product.
2023-04-19 17:30:12 +00:00
|
|
|
insert into invoice_product (invoice_id, name, description, price, quantity, discount_rate)
|
2023-02-16 22:09:10 +00:00
|
|
|
select iid
|
|
|
|
, product.name
|
|
|
|
, coalesce(product.description, '')
|
|
|
|
, parse_price(product.price, currency.decimal_digits)
|
|
|
|
, product.quantity
|
|
|
|
, product.discount_rate
|
|
|
|
from currency
|
|
|
|
where currency_code = ccode
|
|
|
|
returning invoice_product_id
|
|
|
|
into ipid;
|
|
|
|
|
Move the product_id field from invoice_product to a separate table
We are going to allow invoices with products that are not (yet) inserted
into the products table.
We always allowed to have products in invoices with a totally different
name, description, price, and whatnot, but until now we had the product
id in these invoice lines for statistics purposes.
However, Oriol raised the concern that this requires for the products
to be inserted before we can create an invoice with them, and we do not
plan to have a “create product while invoicing” feature, thus it would
mean that people would need to cancel the new invoice, create the new
product, and then start the invoice again from scratch.
The compromise is to allow products in the invoice that do not have a
product_id, meaning that at the time the invoice was created they were
not (yet) in the products table. Oriol sees this stop-invoice-create-
product issue more important than the accurate statistics of product
sales, as it will probably be only one or two units off, anyway.
I did not want to allow NULL values to the invoice product’s product_id
field, because NULL means “dunno” instead of “no product”, so i had to
split that field to a separate table that relates an invoice product
with a registered product.
2023-04-19 17:30:12 +00:00
|
|
|
if product.product_id is not null then
|
|
|
|
insert into invoice_product_product (invoice_product_id, product_id)
|
|
|
|
values (ipid, product.product_id);
|
|
|
|
end if;
|
|
|
|
|
2023-02-16 22:09:10 +00:00
|
|
|
insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate)
|
|
|
|
select ipid, tax_id, tax.rate
|
|
|
|
from tax
|
|
|
|
join unnest(product.tax) as ptax(tax_id) using (tax_id);
|
|
|
|
end loop;
|
|
|
|
|
|
|
|
return pslug;
|
|
|
|
end;
|
|
|
|
$$
|
|
|
|
language plpgsql;
|
|
|
|
|
Remove the number field from new invoice form
Initially, this field was meant to be left almost always blank, except
for when we deleted invoiced and had to “replace” its number with a new
invoice; using the automatic numbering in this cas would not “fill in”
the missing number in the sequence.
However, we decide to not allow removing invoicer not edit their
numbers, therefore, if everything goes as planned, there should not be
any gap in the sequence, and that field is rendered useless.
Oriol suggested making it a read-only field, both for new and edit
forms, but i do not think it makes sense to have a field if you can not
edit it at all, specially in the new invoice dialog, where it would
always be blank. In the edit form we already show the number in the
title and breadcrumbs, thus no need for the read-only field as
reference.
I still keep a Number member to the form struct, but is now a string
(kind of “a read-only field”, in a way) and just to be written in the
title or breadcrumbs. I did not like the idea of adding a new SQL
query just for that value.
2023-04-01 13:57:56 +00:00
|
|
|
revoke execute on function add_invoice(integer, date, integer, text, integer, tag_name[], new_invoice_product[]) from public;
|
|
|
|
grant execute on function add_invoice(integer, date, integer, text, integer, tag_name[], new_invoice_product[]) to invoicer;
|
|
|
|
grant execute on function add_invoice(integer, date, integer, text, integer, tag_name[], new_invoice_product[]) to admin;
|
2023-02-16 22:09:10 +00:00
|
|
|
|
|
|
|
commit;
|