2023-03-11 19:58:20 +00:00
|
|
|
-- Deploy numerus:edit_invoice to pg
|
|
|
|
-- requires: schema_numerus
|
|
|
|
-- requires: invoice
|
|
|
|
-- requires: currency
|
|
|
|
-- requires: parse_price
|
|
|
|
-- requires: edited_invoice_product
|
|
|
|
-- requires: tax
|
|
|
|
-- requires: invoice_product
|
|
|
|
-- requires: invoice_product_tax
|
|
|
|
-- requires: tag_name
|
|
|
|
|
|
|
|
begin;
|
|
|
|
|
|
|
|
set search_path to numerus, public;
|
|
|
|
|
|
|
|
create or replace function edit_invoice(invoice_slug uuid, invoice_status text, contact_id integer, notes text, payment_method_id integer, tags tag_name[], products edited_invoice_product[]) returns uuid as
|
|
|
|
$$
|
|
|
|
declare
|
|
|
|
iid integer;
|
|
|
|
products_to_keep integer[];
|
2023-03-13 13:32:02 +00:00
|
|
|
products_to_delete integer[];
|
2023-03-11 19:58:20 +00:00
|
|
|
company integer;
|
|
|
|
ccode text;
|
|
|
|
product edited_invoice_product;
|
|
|
|
ipid integer;
|
|
|
|
begin
|
|
|
|
update invoice
|
|
|
|
set contact_id = edit_invoice.contact_id
|
|
|
|
, invoice_status = edit_invoice.invoice_status
|
|
|
|
, notes = edit_invoice.notes
|
|
|
|
, payment_method_id = edit_invoice.payment_method_id
|
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 = edit_invoice.tags
|
2023-03-11 19:58:20 +00:00
|
|
|
where slug = invoice_slug
|
|
|
|
returning invoice_id, company_id, currency_code
|
|
|
|
into iid, company, ccode
|
|
|
|
;
|
|
|
|
|
|
|
|
if iid is null then
|
|
|
|
return null;
|
|
|
|
end if;
|
|
|
|
|
|
|
|
foreach product in array products
|
|
|
|
loop
|
|
|
|
if product.invoice_product_id is null then
|
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-03-11 19:58:20 +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;
|
|
|
|
else
|
|
|
|
ipid := product.invoice_product_id;
|
|
|
|
|
|
|
|
update 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
|
|
|
set name = product.name
|
2023-03-11 19:58:20 +00:00
|
|
|
, description = coalesce(product.description, '')
|
|
|
|
, price = parse_price(product.price, currency.decimal_digits)
|
|
|
|
, quantity = product.quantity
|
|
|
|
, discount_rate = product.discount_rate
|
|
|
|
from currency
|
|
|
|
where invoice_product_id = ipid
|
|
|
|
and currency_code = ccode;
|
|
|
|
end if;
|
|
|
|
products_to_keep := array_append(products_to_keep, 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 null then
|
|
|
|
delete from invoice_product_product where invoice_product_id = ipid;
|
|
|
|
else
|
|
|
|
insert into invoice_product_product (invoice_product_id, product_id)
|
|
|
|
values (ipid, product.product_id)
|
|
|
|
on conflict (invoice_product_id) do update
|
|
|
|
set product_id = product.product_id;
|
|
|
|
end if;
|
|
|
|
|
2023-03-11 19:58:20 +00:00
|
|
|
delete from invoice_product_tax where invoice_product_id = ipid;
|
|
|
|
|
|
|
|
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;
|
|
|
|
|
2023-03-13 13:32:02 +00:00
|
|
|
select array_agg(invoice_product_id)
|
|
|
|
into products_to_delete
|
|
|
|
from invoice_product
|
|
|
|
where invoice_id = iid
|
|
|
|
and not (invoice_product_id = any(products_to_keep));
|
|
|
|
|
|
|
|
if array_length(products_to_delete, 1) > 0 then
|
|
|
|
delete from invoice_product_tax where invoice_product_id = any(products_to_delete);
|
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
|
|
|
delete from invoice_product_product where invoice_product_id = any(products_to_delete);
|
2023-03-13 13:32:02 +00:00
|
|
|
delete from invoice_product where invoice_product_id = any(products_to_delete);
|
|
|
|
end if;
|
2023-03-11 19:58:20 +00:00
|
|
|
|
|
|
|
return invoice_slug;
|
|
|
|
end;
|
|
|
|
$$
|
|
|
|
language plpgsql;
|
|
|
|
|
|
|
|
revoke execute on function edit_invoice(uuid, text, integer, text, integer, tag_name[], edited_invoice_product[]) from public;
|
|
|
|
grant execute on function edit_invoice(uuid, text, integer, text, integer, tag_name[], edited_invoice_product[]) to invoicer;
|
|
|
|
grant execute on function edit_invoice(uuid, text, integer, text, integer, tag_name[], edited_invoice_product[]) to admin;
|
|
|
|
|
|
|
|
|
|
|
|
commit;
|