numerus/deploy/edit_contact.sql
jordi fita mas 20827b2cfb Add IBAN and BIC fields to contacts
These two fields are just for information purposes, as Numerus does not
have any way to wire transfer using these, but people might want to keep
these in the contact’s info as a convenience.

Since not every contact should have an IBAN, e.g., customers, and inside
SEPA (European Union and some more countries) the BIC is not required,
they are in two different relations in order to be optional without
using NULL.

For the IBAN i found an already made PostgreSQL module, but for BIC i
had to write a regular expression based on the information i gathered
from Wikipedia, because the ISO standard is not free.

These two parameters for the add_contact and edit_contact functions are
TEXT because i realized that these functions are intended to be used
from the web application, that only deals with texts, so the
ValueOrNil() function was unnecessarily complex and PostreSQL’s
functions were better suited to “convert” from TEXT to IBAN or BIC.
The same is true for EMAIL and URI domains, so i changed their parameter
types to TEXT too.

Closes #54.
2023-07-02 02:08:45 +02:00

132 lines
3.5 KiB
PL/PgSQL

-- Deploy numerus:edit_contact to pg
-- requires: schema_numerus
-- requires: email
-- requires: extension_uri
-- requires: country_code
-- requires: tag_name
-- requires: contact
-- requires: extension_vat
-- requires: extension_pg_libphonenumber
-- requires: tax_details
-- requires: contact_web
-- requires: contact_phone
-- requires: contact_tax_details
-- requires: contact_iban
-- requires: contact_bic
begin;
set search_path to numerus, public;
create or replace function edit_contact(contact_slug uuid, name text, phone text, email text, web text, tax_details tax_details, iban text, bic text, tags tag_name[]) returns uuid as
$$
declare
cid integer;
company integer;
begin
update contact
set name = edit_contact.name
, tags = edit_contact.tags
where slug = contact_slug
returning contact_id, company_id
into cid, company
;
if cid is null then
return null;
end if;
if tax_details is null then
delete
from contact_tax_details
where contact_id = cid
;
else
insert into contact_tax_details (contact_id, business_name, vatin, address, city, province, postal_code, country_code)
values (cid, tax_details.business_name, (tax_details.country_code || tax_details.vatin)::vatin, tax_details.address, tax_details.city, tax_details.province, tax_details.postal_code, tax_details.country_code)
on conflict (contact_id) do update
set business_name = excluded.business_name
, vatin = excluded.vatin
, address = excluded.address
, city = excluded.city
, province = excluded.province
, postal_code = excluded.postal_code
, country_code = excluded.country_code
;
end if;
if phone is null or trim(phone) = '' then
delete from contact_phone
where contact_id = cid
;
else
insert into contact_phone (contact_id, phone)
values (cid, parse_packed_phone_number(edit_contact.phone, coalesce(tax_details.country_code, 'ES')))
on conflict (contact_id) do update
set phone = excluded.phone
;
end if;
if email is null or trim(email) = '' then
delete from contact_email
where contact_id = cid
;
else
insert into contact_email (contact_id, email)
values (cid, edit_contact.email)
on conflict (contact_id) do update
set email = excluded.email
;
end if;
if web is null or trim(web) = '' then
delete from contact_web
where contact_id = cid
;
else
insert into contact_web (contact_id, uri)
values (cid, edit_contact.web)
on conflict (contact_id) do update
set uri = excluded.uri
;
end if;
if iban is null or trim(iban) = '' then
delete from contact_iban
where contact_id = cid
;
else
insert into contact_iban (contact_id, iban)
values (cid, edit_contact.iban)
on conflict (contact_id) do update
set iban = excluded.iban
;
end if;
if bic is null or trim(bic) = '' then
delete from contact_swift
where contact_id = cid
;
else
insert into contact_swift (contact_id, bic)
values (cid, edit_contact.bic)
on conflict (contact_id) do update
set bic = excluded.bic
;
end if;
return contact_slug;
end
$$
language plpgsql
;
revoke execute on function edit_contact(uuid, text, text, text, text, tax_details, text, text, tag_name[]) from public;
grant execute on function edit_contact(uuid, text, text, text, text, tax_details, text, text, tag_name[]) to invoicer;
grant execute on function edit_contact(uuid, text, text, text, text, tax_details, text, text, tag_name[]) to admin;
drop function if exists edit_contact(uuid, text, text, text, text, email, uri, text, text, text, text, country_code, tag_name[]);
commit;