Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
-- 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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
-- requires: input_is_valid
|
|
|
|
-- requires: input_is_valid_phone
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
|
|
|
|
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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
and input_is_valid(country_code || vatin, 'vatin')
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
and input_is_valid(email, 'email')
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
and input_is_valid(web, 'uri')
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
and input_is_valid(iban, 'iban')
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
and input_is_valid(bic, 'bic')
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
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
|
Create validation function for SQL domains and for phones
When i wrote the functions to import contact, i already created a couple
of “temporary” functions to validate whether the input given from the
Excel files was correct according to the various domains used in the
relations, so i can know whether i can import that data.
I realized that i could do exactly the same when validating forms: check
that the value conforms to the domain, in the exact same way, so i can
make sure that the value will be accepted without duplicating the logic,
at the expense of a call to the database.
In an ideal world, i would use pg_input_is_valid, but this function is
only available in PostgreSQL 16 and Debian 12 uses PostgreSQL 15.
These functions are in the public schema because initially i wanted to
use them to also validate email, which is needed in the login form, but
then i recanted and kept the same email validation in Go, because
something felt off about using the database for that particular form,
but i do not know why.
2023-07-03 09:31:59 +00:00
|
|
|
and input_is_valid_phone(phone, case when country_code = '' then 'ES' else country_code end)
|
Allow importing contacts from Holded
This allows to import an Excel file exported from Holded, because it is
our own user case. When we have more customers, we will give out an
Excel template file to fill out.
Why XLSX files instead of CSV, for instance? First, because this is the
output from Holded, but even then we would have more trouble with CSV
than with XLSX because of Microsoft: they royally fucked up
interoperability when decided that CSV files, the files that only other
applications or programmers see, should be “localized”, and use a comma
or a **semicolon** to separate a **comma** separated file depending on
the locale’s decimal separator.
This is ridiculous because it means that CSV files created with an Excel
in USA uses comma while the same Excel but with a French locale expects
the fields to be separated by semicolon. And for no good reason,
either.
Since they fucked up so bad, decided to add a non-standard “meta” field
to specify the separator, writing a `sep=,` in the first line, but this
only works for reading, because saving the same file changes the
separator back to the locale-dependent character and removes the “meta”
field.
And since everyone expects to open spreadsheet with Excel, i can not
use CSV if i do not want a bunch of support tickets telling me that the
template is all in a single line.
I use an extremely old version of a xlsx reading library for golang[0]
because it is already available in Debian repositories, and the only
thing i want from it is to convert the convoluted XML file into a
string array.
Go is only responsible to read the file and dump its contents into a
temporary table, so that it can execute the PL/pgSQL function that will
actually move that data to the correct relations, much like add_contact
does but in batch.
In PostgreSQL version 16 they added a pg_input_is_valid function that
i would use to test whether input values really conform to domains,
but i will have to wait for Debian to pick up the new version.
Meanwhile, i use a couple of temporary functions, in lieu of nested
functions support in PostgreSQL.
Part of #45
[0]: https://github.com/tealeg/xlsx
2023-07-02 22:05:47 +00:00
|
|
|
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;
|