166 lines
4.9 KiB
PL/PgSQL
166 lines
4.9 KiB
PL/PgSQL
-- Deploy numerus:import_contact to pg
|
|
-- requires: schema_numerus
|
|
-- requires: roles
|
|
-- requires: contact
|
|
-- requires: contact_web
|
|
-- requires: contact_phone
|
|
-- requires: contact_email
|
|
-- requires: contact_iban
|
|
-- requires: contact_swift
|
|
-- requires: contact_tax_details
|
|
-- requires: input_is_valid
|
|
-- requires: input_is_valid_phone
|
|
|
|
begin;
|
|
|
|
set search_path to numerus, public;
|
|
|
|
create or replace function begin_import_contacts() returns name as
|
|
$$
|
|
create temporary table imported_contact (
|
|
contact_id integer
|
|
, name text not null default ''
|
|
, vatin text not null default ''
|
|
, email text not null default ''
|
|
, phone text not null default ''
|
|
, web text not null default ''
|
|
, address text not null default ''
|
|
, city text not null default ''
|
|
, province text not null default ''
|
|
, postal_code text not null default ''
|
|
, country_code text not null default ''
|
|
, iban text not null default ''
|
|
, bic text not null default ''
|
|
, tags text not null default ''
|
|
);
|
|
select 'imported_contact'::name;
|
|
$$
|
|
language sql;
|
|
|
|
revoke execute on function begin_import_contacts() from public;
|
|
grant execute on function begin_import_contacts() to invoicer;
|
|
grant execute on function begin_import_contacts() to admin;
|
|
|
|
create or replace function end_import_contacts(company_id integer) returns integer as
|
|
$$
|
|
declare
|
|
imported integer;
|
|
begin
|
|
update imported_contact
|
|
set country_code = upper(trim(country_code))
|
|
, name = trim(name)
|
|
, vatin = trim(vatin)
|
|
, email = trim(email)
|
|
, phone = trim(phone)
|
|
, web = trim(web)
|
|
, address = trim(address)
|
|
, city = trim(city)
|
|
, province = trim(province)
|
|
, postal_code = trim(postal_code)
|
|
, iban = trim(iban)
|
|
, bic = trim(bic)
|
|
, tags = lower(trim(regexp_replace(regexp_replace(tags, '[^\sA-Za-z0-9-]', '', 'g'), '\s\s+', ' ', 'g')))
|
|
;
|
|
|
|
update imported_contact
|
|
set contact_id = tax_details.contact_id
|
|
from contact_tax_details as tax_details
|
|
join contact using (contact_id)
|
|
where contact.company_id = end_import_contacts.company_id
|
|
and tax_details.vatin::text = imported_contact.country_code || imported_contact.vatin
|
|
;
|
|
|
|
update imported_contact
|
|
set contact_id = nextval('contact_contact_id_seq'::regclass)
|
|
where length(trim(name)) > 1
|
|
and contact_id is null
|
|
;
|
|
|
|
insert into contact (contact_id, company_id, name, tags)
|
|
select contact_id, end_import_contacts.company_id, name, string_to_array(tags, ' ')::tag_name[]
|
|
from imported_contact
|
|
where contact_id is not null
|
|
on conflict (contact_id) do update
|
|
set tags = array_cat(contact.tags, excluded.tags)
|
|
;
|
|
|
|
insert into contact_tax_details (contact_id, business_name, vatin, address, city, province, postal_code, country_code)
|
|
select contact_id, imported_contact.name, (country_code || vatin)::vatin, address, city, province, postal_code, country_code
|
|
from imported_contact
|
|
join country using (country_code)
|
|
where contact_id is not null
|
|
and length(address) > 1
|
|
and length(city) > 1
|
|
and length(province) > 1
|
|
and postal_code ~ postal_code_regex
|
|
and input_is_valid(country_code || vatin, 'vatin')
|
|
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
|
|
;
|
|
|
|
insert into contact_email (contact_id, email)
|
|
select contact_id, email::email
|
|
from imported_contact
|
|
where contact_id is not null
|
|
and input_is_valid(email, 'email')
|
|
on conflict (contact_id) do update
|
|
set email = excluded.email
|
|
;
|
|
|
|
insert into contact_web (contact_id, uri)
|
|
select contact_id, web::uri
|
|
from imported_contact
|
|
where contact_id is not null
|
|
and input_is_valid(web, 'uri')
|
|
and length(web) > 1
|
|
on conflict (contact_id) do update
|
|
set uri = excluded.uri
|
|
;
|
|
|
|
insert into contact_iban (contact_id, iban)
|
|
select contact_id, iban::iban
|
|
from imported_contact
|
|
where contact_id is not null
|
|
and input_is_valid(iban, 'iban')
|
|
on conflict (contact_id) do update
|
|
set iban = excluded.iban
|
|
;
|
|
|
|
insert into contact_swift (contact_id, bic)
|
|
select contact_id, bic::bic
|
|
from imported_contact
|
|
where contact_id is not null
|
|
and input_is_valid(bic, 'bic')
|
|
on conflict (contact_id) do update
|
|
set bic = excluded.bic
|
|
;
|
|
|
|
insert into contact_phone (contact_id, phone)
|
|
select contact_id, parse_packed_phone_number(phone, case when country_code = '' then 'ES' else country_code end)
|
|
from imported_contact
|
|
where contact_id is not null
|
|
and input_is_valid_phone(phone, case when country_code = '' then 'ES' else country_code end)
|
|
on conflict (contact_id) do update
|
|
set phone = excluded.phone
|
|
;
|
|
|
|
select count(*) from imported_contact where contact_id is not null into imported;
|
|
return imported;
|
|
|
|
drop table imported_contact;
|
|
end
|
|
$$
|
|
language plpgsql;
|
|
|
|
revoke execute on function end_import_contacts(integer) from public;
|
|
grant execute on function end_import_contacts(integer) to invoicer;
|
|
grant execute on function end_import_contacts(integer) to admin;
|
|
|
|
commit;
|