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
-- Test import_contact
set client_min_messages to warning ;
create extension if not exists pgtap ;
reset client_min_messages ;
begin ;
select plan ( 27 ) ;
set search_path to numerus , auth , public ;
select has_function ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] ) ;
select function_lang_is ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' sql ' ) ;
select function_returns ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' name ' ) ;
select isnt_definer ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] ) ;
select volatility_is ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' volatile ' ) ;
select function_privs_are ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' guest ' , array [ ] : : text [ ] ) ;
select function_privs_are ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' invoicer ' , array [ ' EXECUTE ' ] ) ;
select function_privs_are ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' admin ' , array [ ' EXECUTE ' ] ) ;
select function_privs_are ( ' numerus ' , ' begin_import_contacts ' , array [ ] : : name [ ] , ' authenticator ' , array [ ] : : text [ ] ) ;
select has_function ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] ) ;
select function_lang_is ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' plpgsql ' ) ;
select function_returns ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' integer ' ) ;
select isnt_definer ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] ) ;
select volatility_is ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' volatile ' ) ;
select function_privs_are ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' guest ' , array [ ] : : text [ ] ) ;
select function_privs_are ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' invoicer ' , array [ ' EXECUTE ' ] ) ;
select function_privs_are ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' admin ' , array [ ' EXECUTE ' ] ) ;
select function_privs_are ( ' numerus ' , ' end_import_contacts ' , array [ ' integer ' ] , ' authenticator ' , array [ ] : : text [ ] ) ;
set client_min_messages to warning ;
truncate contact_swift cascade ;
truncate contact_iban cascade ;
truncate contact_web cascade ;
truncate contact_email cascade ;
truncate contact_phone cascade ;
truncate contact_tax_details cascade ;
truncate contact cascade ;
truncate payment_method cascade ;
truncate company cascade ;
reset client_min_messages ;
set constraints " company_default_payment_method_id_fkey " deferred ;
insert into company ( company_id , business_name , vatin , trade_name , phone , email , web , address , city , province , postal_code , country_code , currency_code , default_payment_method_id )
values ( 1 , ' Company 2 ' , ' XX123 ' , ' ' , ' 555-555-555 ' , ' a@a ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ES ' , ' EUR ' , 111 )
;
insert into payment_method ( payment_method_id , company_id , name , instructions )
values ( 111 , 1 , ' cash ' , ' cash ' )
, ( 112 , 1 , ' bank ' , ' send money to my bank account ' )
;
set constraints " company_default_payment_method_id_fkey " immediate ;
insert into contact ( contact_id , company_id , slug , name , tags )
values ( 12 , 1 , ' 7ac3ae0e-b0c1-4206-a19b-0be20835edd4 ' , ' Contact 1 ' , ' {tag1} ' )
, ( 13 , 1 , ' b57b980b-247b-4be4-a0b7-03a7819c53ae ' , ' Contact 2 ' , ' {tag2} ' )
;
insert into contact_tax_details ( contact_id , business_name , vatin , address , city , province , postal_code , country_code )
values ( 12 , ' Contact 1 Ltd ' , ' ES41414141L ' , ' One Road ' , ' One City ' , ' One Province ' , ' 17001 ' , ' ES ' )
, ( 13 , ' Contact 2 Ltd ' , ' ES42424242Y ' , ' Two Road ' , ' Two City ' , ' Two Province ' , ' 17002 ' , ' ES ' )
;
insert into contact_phone ( contact_id , phone )
values ( 12 , ' 777-777-777 ' )
, ( 13 , ' 888-888-888 ' )
;
insert into contact_email ( contact_id , email )
values ( 12 , ' c@c ' )
, ( 13 , ' d@d ' )
;
insert into contact_web ( contact_id , uri )
values ( 12 , ' https://1/ ' )
, ( 13 , ' https://2/ ' )
;
insert into contact_iban ( contact_id , iban )
values ( 12 , ' NL04RABO9373475770 ' )
, ( 13 , ' NL17RABO4416709382 ' )
;
insert into contact_swift ( contact_id , bic )
values ( 12 , ' ABNANL2A ' )
, ( 13 , ' ARBNNL22 ' )
;
2023-07-02 22:25:17 +00:00
-- make sure there is no overlap with selected id above when importing new contacts
alter sequence contact_contact_id_seq restart with 14 ;
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
select is ( begin_import_contacts ( ) , ' imported_contact ' , ' Should return the name of the relation to import ' ) ;
insert into imported_contact ( name , vatin , email , phone , web , address , city , province , postal_code , country_code , iban , bic , tags )
values ( ' Contact 1 S.L. ' , ' 41414141L ' , ' a@a ' , ' 111-111-111 ' , ' https://a/ ' , ' Fake St., 123 ' , ' Fake City ' , ' Fake province ' , ' 17000 ' , ' ES ' , ' NL73INGB9691012820 ' , ' EMCFNLKEX30 ' , ' #updated ' ) -- valid updated contact
, ( ' Contact 2 Ltd ' , ' 42424242Y ' , ' d@d ' , ' 888-888-888 ' , ' https://2/ ' , ' ' , ' ' , ' ' , ' ' , ' ES ' , ' NL17RABO4416709382 ' , ' ARBNNL22 ' , ' ' ) -- valid existing contact, with same data but missing taxt details; leave what we already had
, ( ' Contact 3 ' , ' 43434343Q ' , ' e@e ' , ' 999-999-999 ' , ' invalid uri ' , ' Three Road ' , ' Three City ' , ' Three Province ' , ' 17003 ' , ' FR ' , ' NL77INGB8674905641 ' , ' EMCFNLKEXXX ' , ' #new ' ) -- valid new contact
, ( ' Contact 4.1 ' , ' 44444444B ' , ' invalid email ' , ' 000-000-000 ' , ' ' , ' Four Road ' , ' Four City ' , ' Four Province ' , ' 17004 ' , ' ES ' , ' invalid iban ' , ' EMCFNLKEX20 ' , ' #missing #details #vatin ' ) -- invalid vatin: no tax details added
, ( ' Contact 4.2 ' , ' 44444444A ' , ' f@f ' , ' invalid phone ' , ' ' , ' ' , ' Four City ' , ' Four Province ' , ' 17004 ' , ' ES ' , ' NL50RABO9661117578 ' , ' invalid bic ' , ' #missing #details #street ' ) -- invalid street: no tax details added
, ( ' Contact 4.3 ' , ' 44444444A ' , ' ' , ' ' , ' https://4/ ' , ' Four Road ' , ' ' , ' Four Province ' , ' 17004 ' , ' ES ' , ' ' , ' ' , ' #missing #details #city #$$$$ ' ) -- invalid city: no tax details added
, ( ' Contact 4.4 ' , ' 44444444A ' , ' ' , ' ' , ' ' , ' Four Road ' , ' Four City ' , ' ' , ' 17004 ' , ' ES ' , ' ' , ' ' , ' #missing #details #Pro$vince ' ) -- invalid province: no tax details added
, ( ' Contact 4.5 ' , ' 44444444A ' , ' ' , ' ' , ' ' , ' Four Road ' , ' Four City ' , ' Four Province ' , ' ' , ' ES ' , ' ' , ' ' , ' #missing #det/ails #postal code ' ) -- invalid postal code: no tax details added
, ( ' Contact 4.6 ' , ' 44444444A ' , ' ' , ' ' , ' ' , ' Four Road ' , ' Four City ' , ' Four Province ' , ' 17004 ' , ' ' , ' ' , ' ' , ' #mis-sing #details #country ' ) -- invalid country code: no tax details added
, ( ' Contact 5 ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' ' , ' just name ' ) -- valid new contact with just a name
, ( ' ' , ' 44444444A ' , ' valid@email.com ' , ' 111 111 111 ' , ' https://3/ ' , ' Fake St., 123 ' , ' City ' , ' Province ' , ' 17486 ' , ' ES ' , ' NL04RABO9373475770 ' , ' ARBNNL22 ' , ' tag1 tag2 ' ) -- contact with invalid name — not added
;
select is ( end_import_contacts ( 1 ) , 10 , ' Should have imported all contacts with mostly correct data ' ) ;
select bag_eq (
$ $ select company_id , name , tags from contact $ $ ,
$ $ values ( 1 , ' Contact 1 ' , ' {tag1,updated} ' : : tag_name [ ] )
, ( 1 , ' Contact 2 ' , ' {tag2} ' : : tag_name [ ] )
, ( 1 , ' Contact 3 ' , ' {new} ' : : tag_name [ ] )
, ( 1 , ' Contact 4.1 ' , ' {missing,details,vatin} ' : : tag_name [ ] )
, ( 1 , ' Contact 4.2 ' , ' {missing,details,street} ' : : tag_name [ ] )
, ( 1 , ' Contact 4.3 ' , ' {missing,details,city} ' : : tag_name [ ] )
, ( 1 , ' Contact 4.4 ' , ' {missing,details,province} ' : : tag_name [ ] )
, ( 1 , ' Contact 4.5 ' , ' {missing,details,postal,code} ' : : tag_name [ ] )
, ( 1 , ' Contact 4.6 ' , ' {mis-sing,details,country} ' : : tag_name [ ] )
, ( 1 , ' Contact 5 ' , ' {just,name} ' : : tag_name [ ] )
$ $ ,
' Should have created all contacts '
) ;
select bag_eq (
$ $ select name , business_name , vatin : : text , address , city , province , postal_code , country_code : : text from contact join contact_tax_details using ( contact_id ) $ $ ,
$ $ values ( ' Contact 1 ' , ' Contact 1 S.L. ' , ' ES41414141L ' , ' Fake St., 123 ' , ' Fake City ' , ' Fake province ' , ' 17000 ' , ' ES ' )
, ( ' Contact 2 ' , ' Contact 2 Ltd ' , ' ES42424242Y ' , ' Two Road ' , ' Two City ' , ' Two Province ' , ' 17002 ' , ' ES ' )
, ( ' Contact 3 ' , ' Contact 3 ' , ' FR43434343Q ' , ' Three Road ' , ' Three City ' , ' Three Province ' , ' 17003 ' , ' FR ' )
$ $ ,
' Should have created all contacts’ tax details '
) ;
select bag_eq (
$ $ select name , phone : : text from contact join contact_phone using ( contact_id ) $ $ ,
$ $ values ( ' Contact 1 ' , ' +34 111111111 ' )
, ( ' Contact 2 ' , ' +34 888 88 88 88 ' )
, ( ' Contact 3 ' , ' +33 9 99 99 99 99 ' )
, ( ' Contact 4.1 ' , ' +34 000000000 ' )
$ $ ,
' Should have created all contacts’ phone '
) ;
select bag_eq (
$ $ select name , email : : text from contact join contact_email using ( contact_id ) $ $ ,
$ $ values ( ' Contact 1 ' , ' a@a ' )
, ( ' Contact 2 ' , ' d@d ' )
, ( ' Contact 3 ' , ' e@e ' )
, ( ' Contact 4.2 ' , ' f@f ' )
$ $ ,
' Should have created all contacts’ email '
) ;
select bag_eq (
$ $ select name , uri : : text from contact join contact_web using ( contact_id ) $ $ ,
$ $ values ( ' Contact 1 ' , ' https://a/ ' )
, ( ' Contact 2 ' , ' https://2/ ' )
, ( ' Contact 4.3 ' , ' https://4/ ' )
$ $ ,
' Should have created all contacts’ web '
) ;
select bag_eq (
$ $ select name , iban : : text from contact join contact_iban using ( contact_id ) $ $ ,
$ $ values ( ' Contact 1 ' , ' NL73INGB9691012820 ' )
, ( ' Contact 2 ' , ' NL17RABO4416709382 ' )
, ( ' Contact 3 ' , ' NL77INGB8674905641 ' )
, ( ' Contact 4.2 ' , ' NL50RABO9661117578 ' )
$ $ ,
' Should have created all contacts’ IBAN '
) ;
select bag_eq (
$ $ select name , bic : : text from contact join contact_swift using ( contact_id ) $ $ ,
$ $ values ( ' Contact 1 ' , ' EMCFNLKEX30 ' )
, ( ' Contact 2 ' , ' ARBNNL22 ' )
, ( ' Contact 3 ' , ' EMCFNLKEXXX ' )
, ( ' Contact 4.1 ' , ' EMCFNLKEX20 ' )
$ $ ,
' Should have created all contacts’ BIC '
) ;
select *
from finish ( ) ;
rollback ;